Table of Contents
This chapter explains different ways to optimize MySQL and provides examples. Optimization is a complex task because ultimately it requires understanding of the entire system to be optimized. Although it may be possible to perform some local optimizations with little knowledge of your system or application, the more optimal you want your system to become, the more you must know about it.
The most important factor in making a system fast is its basic design. You must also know what kinds of processing your system is doing, and what its bottlenecks are. In most cases, system bottlenecks arise from these sources:
Disk seeks. It takes time for the disk to find a piece of data. With modern disks, the mean time for this is usually lower than 10ms, so we can in theory do about 100 seeks a second. This time improves slowly with new disks and is very hard to optimize for a single table. The way to optimize seek time is to distribute the data onto more than one disk.
Disk reading and writing. When the disk is at the correct position, we need to read the data. With modern disks, one disk delivers at least 10–20MB/s throughput. This is easier to optimize than seeks because you can read in parallel from multiple disks.
CPU cycles. When we have the data in main memory, we need to process it to get our result. Having small tables compared to the amount of memory is the most common limiting factor. But with small tables, speed is usually not the problem.
Memory bandwidth. When the CPU needs more data than can fit in the CPU cache, main memory bandwidth becomes a bottleneck. This is an uncommon bottleneck for most systems, but one to be aware of.
When using the MyISAM storage engine, MySQL
uses extremely fast table locking that permits multiple readers
or a single writer. The biggest problem with this storage engine
occurs when you have a steady stream of mixed updates and slow
selects on a single table. If this is a problem for certain
tables, you can use another storage engine for them. See
Chapter 13, Storage Engines.
MySQL can work with both transactional and nontransactional
tables. To make it easier to work smoothly with nontransactional
tables (which cannot roll back if something goes wrong), MySQL
has the following rules. Note that these rules apply
only when not running in strict SQL mode or
if you use the IGNORE specifier for
INSERT or
UPDATE.
All columns have default values.
If you insert an inappropriate or out-of-range value into a column, MySQL sets the column to the “best possible value” instead of reporting an error. For numeric values, this is 0, the smallest possible value or the largest possible value. For strings, this is either the empty string or as much of the string as can be stored in the column.
All calculated expressions return a value that can be used
instead of signaling an error condition. For example, 1/0
returns NULL.
To change the preceding behaviors, you can enable stricter data
handling by setting the server SQL mode appropriately. For more
information about data handling, see
Section 1.8.6, “How MySQL Deals with Constraints”,
Section 5.1.7, “Server SQL Modes”, and Section 12.2.5, “INSERT Syntax”.
Because all SQL servers implement different parts of standard SQL, it takes work to write portable database applications. It is very easy to achieve portability for very simple selects and inserts, but becomes more difficult the more capabilities you require. If you want an application that is fast with many database systems, it becomes even more difficult.
All database systems have some weak points. That is, they have different design compromises that lead to different behavior.
To make a complex application portable, you need to determine which SQL servers it must work with, and then determine what features those servers support. You can use the MySQL crash-me program to find functions, types, and limits that you can use with a selection of database servers. crash-me does not check for every possible feature, but it is still reasonably comprehensive, performing about 450 tests. An example of the type of information crash-me can provide is that you should not use column names that are longer than 18 characters if you want to be able to use Informix or DB2.
The crash-me program and the MySQL benchmarks
are all very database independent. By taking a look at how they
are written, you can get a feeling for what you must do to make
your own applications database independent. The programs can be
found in the sql-bench directory of MySQL
source distributions. They are written in Perl and use the DBI
database interface. Use of DBI in itself solves part of the
portability problem because it provides database-independent
access methods. See Section 7.1.3, “The MySQL Benchmark Suite”.
If you strive for database independence, you need to get a good
feeling for each SQL server's bottlenecks. For example, MySQL is
very fast in retrieving and updating rows for
MyISAM tables, but has a problem in mixing
slow readers and writers on the same table. Transactional
database systems in general are not very good at generating
summary tables from log tables, because in this case row locking
is almost useless.
To make your application really database independent, you should define an easily extendable interface through which you manipulate your data. For example, C++ is available on most systems, so it makes sense to use a C++ class-based interface to the databases.
If you use some feature that is specific to a given database
system (such as the REPLACE
statement, which is specific to MySQL), you should implement the
same feature for other SQL servers by coding an alternative
method. Although the alternative might be slower, it enables the
other servers to perform the same tasks.
With MySQL, you can use the /*! */ syntax to
add MySQL-specific keywords to a statement. The code inside
/* */ is treated as a comment (and ignored)
by most other SQL servers. For information about writing
comments, see Section 8.6, “Comment Syntax”.
If high performance is more important than exactness, as for some Web applications, it is possible to create an application layer that caches all results to give you even higher performance. By letting old results expire after a while, you can keep the cache reasonably fresh. This provides a method to handle high load spikes, in which case you can dynamically increase the cache size and set the expiration timeout higher until things get back to normal.
In this case, the table creation information should contain information about the initial cache size and how often the table should normally be refreshed.
An attractive alternative to implementing an application cache is to use the MySQL query cache. By enabling the query cache, the server handles the details of determining whether a query result can be reused. This simplifies your application. See Section 7.6.3, “The MySQL Query Cache”.
This benchmark suite is meant to tell any user what operations a
given SQL implementation performs well or poorly. You can get a
good idea for how the benchmarks work by looking at the code and
results in the sql-bench directory in any
MySQL source distribution.
Note that this benchmark is single-threaded, so it measures the minimum time for the operations performed. We plan to add multi-threaded tests to the benchmark suite in the future.
To use the benchmark suite, the following requirements must be satisfied:
The benchmark suite is provided with MySQL source distributions. You can either download a released distribution from http://dev.mysql.com/downloads/, or use the current development source tree. (See Section 2.11.4, “Installing from the Development Source Tree”.)
The benchmark scripts are written in Perl and use the Perl
DBI module to access database servers, so DBI must be
installed. You also need the server-specific DBD drivers for
each of the servers you want to test. For example, to test
MySQL, PostgreSQL, and DB2, you must have the
DBD::mysql, DBD::Pg,
and DBD::DB2 modules installed. See
Section 2.15, “Perl Installation Notes”.
After you obtain a MySQL source distribution, you can find the
benchmark suite located in its sql-bench
directory. To run the benchmark tests, build MySQL, and then
change location into the sql-bench
directory and execute the run-all-tests
script:
shell>cd sql-benchshell>perl run-all-tests --server=server_name
server_name should be the name of one
of the supported servers. To get a list of all options and
supported servers, invoke this command:
shell> perl run-all-tests --help
The crash-me script also is located in the
sql-bench directory.
crash-me tries to determine what features a
database system supports and what its capabilities and
limitations are by actually running queries. For example, it
determines:
What data types are supported
How many indexes are supported
What functions are supported
How big a query can be
How big a VARCHAR column can
be
For more information about benchmark results, visit http://www.mysql.com/why-mysql/benchmarks/.
You should definitely benchmark your application and database to find out where the bottlenecks are. After fixing one bottleneck (or by replacing it with a “dummy” module), you can proceed to identify the next bottleneck. Even if the overall performance for your application currently is acceptable, you should at least make a plan for each bottleneck and decide how to solve it if someday you really need the extra performance.
For examples of portable benchmark programs, look at those in the MySQL benchmark suite. See Section 7.1.3, “The MySQL Benchmark Suite”. You can take any program from this suite and modify it for your own needs. By doing this, you can try different solutions to your problem and test which really is fastest for you.
Another free benchmark suite is the Open Source Database Benchmark, available at http://osdb.sourceforge.net/.
It is very common for a problem to occur only when the system is very heavily loaded. We have had many customers who contact us when they have a (tested) system in production and have encountered load problems. In most cases, performance problems turn out to be due to issues of basic database design (for example, table scans are not good under high load) or problems with the operating system or libraries. Most of the time, these problems would be much easier to fix if the systems were not already in production.
To avoid problems like this, you should put some effort into benchmarking your whole application under the worst possible load:
The mysqlslap program can be helpful for simulating a high load produced by multiple clients issuing queries simultaneously. See Section 4.5.7, “mysqlslap — Load Emulation Client”.
You can also try Super Smack, available at http://jeremy.zawodny.com/mysql/super-smack/.
As suggested by the names of these programs, they can bring a system to its knees, so make sure to use them only on your development systems.
The EXPLAIN statement can be used
either as a synonym for DESCRIBE
or as a way to obtain information about how MySQL executes a
SELECT statement:
EXPLAIN
is synonymous
with tbl_nameDESCRIBE
or
tbl_nameSHOW COLUMNS FROM
:
tbl_name
EXPLAIN tbl_name
When you precede a SELECT
statement with the keyword
EXPLAIN, MySQL displays
information from the optimizer about the query execution
plan. That is, MySQL explains how it would process the
SELECT, including information
about how tables are joined and in which order:
EXPLAIN [EXTENDED | PARTITIONS] SELECT select_options
EXPLAIN
PARTITIONS is available beginning with MySQL
5.1.5. It is useful only when examining queries involving
partitioned tables. For details, see
Section 18.3.4, “Obtaining Information About Partitions”.
This section describes the second use of
EXPLAIN for obtaining query
execution plan information. See also Section 12.8.2, “EXPLAIN Syntax”.
For a description of the DESCRIBE
and SHOW COLUMNS statements, see
Section 12.8.1, “DESCRIBE Syntax”, and Section 12.4.5.6, “SHOW COLUMNS Syntax”.
With the help of EXPLAIN, you can
see where you should add indexes to tables to get a faster
SELECT that uses indexes to find
rows. You can also use EXPLAIN to
check whether the optimizer joins the tables in an optimal
order. To give a hint to the optimizer to use a join order
corresponding to the order in which the tables are named in the
SELECT statement, begin the
statement with SELECT STRAIGHT_JOIN rather
than just SELECT. (See
Section 12.2.8, “SELECT Syntax”.)
If you have a problem with indexes not being used when you
believe that they should be, you should run
ANALYZE TABLE to update table
statistics such as cardinality of keys, that can affect the
choices the optimizer makes. See
Section 12.4.2.1, “ANALYZE TABLE Syntax”.
EXPLAIN returns a row of
information for each table used in the
SELECT statement. The tables are
listed in the output in the order that MySQL would read them
while processing the query. MySQL resolves all joins using a
nested-loop join method. This means that MySQL reads a row from
the first table, and then finds a matching row in the second
table, the third table, and so on. When all tables are
processed, MySQL outputs the selected columns and backtracks
through the table list until a table is found for which there
are more matching rows. The next row is read from this table and
the process continues with the next table.
When the EXTENDED keyword is used,
EXPLAIN produces extra
information that can be viewed by issuing a
SHOW WARNINGS statement following
the EXPLAIN statement. This
information displays how the optimizer qualifies table and
column names in the SELECT
statement, what the SELECT looks
like after the application of rewriting and optimization rules,
and possibly other notes about the optimization process.
EXPLAIN
EXTENDED also displays the filtered
column as of MySQL 5.1.12.
You cannot use the EXTENDED and
PARTITIONS keywords together in the same
EXPLAIN statement.
Each output row from EXPLAIN
provides information about one table, and each row contains the
following columns:
id
The SELECT identifier. This
is the sequential number of the
SELECT within the query.
select_type
The type of SELECT, which can
be any of those shown in the following table.
select_type Value | Meaning |
|---|---|
SIMPLE | Simple SELECT (not using
UNION or subqueries) |
PRIMARY | Outermost SELECT |
UNION | Second or later SELECT statement in a
UNION |
DEPENDENT UNION | Second or later SELECT statement in a
UNION, dependent on
outer query |
UNION RESULT | Result of a UNION. |
SUBQUERY | First SELECT in subquery |
DEPENDENT SUBQUERY | First SELECT in subquery, dependent on
outer query |
DERIVED | Derived table SELECT (subquery in
FROM clause) |
UNCACHEABLE SUBQUERY | A subquery for which the result cannot be cached and must be re-evaluated for each row of the outer query |
UNCACHEABLE UNION | The second or later select in a UNION
that belongs to an uncacheable subquery (see
UNCACHEABLE SUBQUERY) |
DEPENDENT typically signifies the use of
a correlated subquery. See
Section 12.2.9.7, “Correlated Subqueries”.
DEPENDENT SUBQUERY evaluation differs
from UNCACHEABLE SUBQUERY evaluation. For
DEPENDENT SUBQUERY, the subquery is
re-evaluated only once for each set of different values of
the variables from its outer context. For
UNCACHEABLE SUBQUERY, the subquery is
re-evaluated for each row of the outer context. Cacheability
of subqueries is subject to the restrictions detailed in
Section 7.6.3.1, “How the Query Cache Operates”. For example,
referring to user variables makes a subquery uncacheable.
table
The table to which the row of output refers.
type
The join type. The different join types are listed here, ordered from the best type to the worst:
The table has only one row (= system table). This is a
special case of the
const join type.
The table has at most one matching row, which is read at
the start of the query. Because there is only one row,
values from the column in this row can be regarded as
constants by the rest of the optimizer.
const tables are very
fast because they are read only once.
const is used when
you compare all parts of a PRIMARY
KEY or UNIQUE index to
constant values. In the following queries,
tbl_name can be used as a
const table:
SELECT * FROMtbl_nameWHEREprimary_key=1; SELECT * FROMtbl_nameWHEREprimary_key_part1=1 ANDprimary_key_part2=2;
One row is read from this table for each combination of
rows from the previous tables. Other than the
system and
const types, this is
the best possible join type. It is used when all parts
of an index are used by the join and the index is a
PRIMARY KEY or UNIQUE NOT
NULL index.
eq_ref can be used
for indexed columns that are compared using the
= operator. The comparison value can
be a constant or an expression that uses columns from
tables that are read before this table. In the following
examples, MySQL can use an
eq_ref join to
process ref_table:
SELECT * FROMref_table,other_tableWHEREref_table.key_column=other_table.column; SELECT * FROMref_table,other_tableWHEREref_table.key_column_part1=other_table.columnANDref_table.key_column_part2=1;
All rows with matching index values are read from this
table for each combination of rows from the previous
tables. ref is used
if the join uses only a leftmost prefix of the key or if
the key is not a PRIMARY KEY or
UNIQUE index (in other words, if the
join cannot select a single row based on the key value).
If the key that is used matches only a few rows, this is
a good join type.
ref can be used for
indexed columns that are compared using the
= or <=>
operator. In the following examples, MySQL can use a
ref join to process
ref_table:
SELECT * FROMref_tableWHEREkey_column=expr; SELECT * FROMref_table,other_tableWHEREref_table.key_column=other_table.column; SELECT * FROMref_table,other_tableWHEREref_table.key_column_part1=other_table.columnANDref_table.key_column_part2=1;
The join is performed using a
FULLTEXT index.
This join type is like
ref, but with the
addition that MySQL does an extra search for rows that
contain NULL values. This join type
optimization is used most often in resolving subqueries.
In the following examples, MySQL can use a
ref_or_null join to
process ref_table:
SELECT * FROMref_tableWHEREkey_column=exprORkey_columnIS NULL;
This join type indicates that the Index Merge
optimization is used. In this case, the
key column in the output row contains
a list of indexes used, and key_len
contains a list of the longest key parts for the indexes
used. For more information, see
Section 7.3.1.4, “Index Merge Optimization”.
This type replaces
ref for some
IN subqueries of the following form:
valueIN (SELECTprimary_keyFROMsingle_tableWHEREsome_expr)
unique_subquery is
just an index lookup function that replaces the subquery
completely for better efficiency.
This join type is similar to
unique_subquery. It
replaces IN subqueries, but it works
for nonunique indexes in subqueries of the following
form:
valueIN (SELECTkey_columnFROMsingle_tableWHEREsome_expr)
Only rows that are in a given range are retrieved, using
an index to select the rows. The key
column in the output row indicates which index is used.
The key_len contains the longest key
part that was used. The ref column is
NULL for this type.
range can be used
when a key column is compared to a constant using any of
the =,
<>,
>,
>=,
<,
<=,
IS NULL,
<=>,
BETWEEN, or
IN() operators:
SELECT * FROMtbl_nameWHEREkey_column= 10; SELECT * FROMtbl_nameWHEREkey_columnBETWEEN 10 and 20; SELECT * FROMtbl_nameWHEREkey_columnIN (10,20,30); SELECT * FROMtbl_nameWHEREkey_part1= 10 ANDkey_part2IN (10,20,30);
This join type is the same as
ALL, except that
only the index tree is scanned. This usually is faster
than ALL because
the index file usually is smaller than the data file.
MySQL can use this join type when the query uses only columns that are part of a single index.
A full table scan is done for each combination of rows
from the previous tables. This is normally not good if
the table is the first table not marked
const, and usually
very bad in all other cases.
Normally, you can avoid
ALL by adding
indexes that enable row retrieval from the table based
on constant values or column values from earlier tables.
possible_keys
The possible_keys column indicates which
indexes MySQL can choose from use to find the rows in this
table. Note that this column is totally independent of the
order of the tables as displayed in the output from
EXPLAIN. That means that some
of the keys in possible_keys might not be
usable in practice with the generated table order.
If this column is NULL, there are no
relevant indexes. In this case, you may be able to improve
the performance of your query by examining the
WHERE clause to check whether it refers
to some column or columns that would be suitable for
indexing. If so, create an appropriate index and check the
query with EXPLAIN again. See
Section 12.1.7, “ALTER TABLE Syntax”.
To see what indexes a table has, use SHOW INDEX
FROM .
tbl_name
key
The key column indicates the key (index)
that MySQL actually decided to use. If MySQL decides to use
one of the possible_keys indexes to look
up rows, that index is listed as the key value.
It is possible that key will name an
index that is not present in the
possible_keys value. This can happen if
none of the possible_keys indexes are
suitable for looking up rows, but all the columns selected
by the query are columns of some other index. That is, the
named index covers the selected columns, so although it is
not used to determine which rows to retrieve, an index scan
is more efficient than a data row scan.
For InnoDB, a secondary index might cover
the selected columns even if the query also selects the
primary key because InnoDB stores the
primary key value with each secondary index. If
key is NULL, MySQL
found no index to use for executing the query more
efficiently.
To force MySQL to use or ignore an index listed in the
possible_keys column, use FORCE
INDEX, USE INDEX, or
IGNORE INDEX in your query. See
Section 12.2.8.2, “Index Hint Syntax”.
For MyISAM tables, running
ANALYZE TABLE helps the
optimizer choose better indexes. For
MyISAM tables, myisamchk
--analyze does the same. See
Section 12.4.2.1, “ANALYZE TABLE Syntax”, and
Section 6.6, “MyISAM Table Maintenance and Crash Recovery”.
key_len
The key_len column indicates the length
of the key that MySQL decided to use. The length is
NULL if the key column
says NULL. Note that the value of
key_len enables you to determine how many
parts of a multiple-part key MySQL actually uses.
ref
The ref column shows which columns or
constants are compared to the index named in the
key column to select rows from the table.
rows
The rows column indicates the number of
rows MySQL believes it must examine to execute the query.
For InnoDB tables, this number
is an estimate, and may not always be exact.
filtered
The filtered column indicates an
estimated percentage of table rows that will be filtered by
the table condition. That is, rows shows
the estimated number of rows examined and
rows × filtered
/ 100 shows the number of rows that will
be joined with previous tables. This column is displayed if
you use EXPLAIN
EXTENDED. (New in MySQL 5.1.12)
Extra
This column contains additional information about how MySQL
resolves the query. The following list explains the values
that can appear in this column. If you want to make your
queries as fast as possible, you should look out for
Extra values of Using
filesort and Using temporary.
const row not found
For a query such as SELECT ... FROM
, the table
was empty.
tbl_name
Distinct
MySQL is looking for distinct values, so it stops searching for more rows for the current row combination after it has found the first matching row.
Full scan on NULL key
This occurs for subquery optimization as a fallback strategy when the optimizer cannot use an index-lookup access method.
Impossible HAVING
The HAVING clause is always false and
cannot select any rows.
Impossible WHERE
The WHERE clause is always false and
cannot select any rows.
Impossible WHERE noticed after reading const
tables
MySQL has read all
const (and
system) tables and
notice that the WHERE clause is
always false.
No matching min/max row
No row satisfies the condition for a query such as
SELECT MIN(...) FROM ... WHERE
.
condition
no matching row in const table
For a query with a join, there was an empty table or a table with no rows satisfying a unique index condition.
No tables used
The query has no FROM clause, or has
a FROM DUAL clause.
Not exists
MySQL was able to do a LEFT JOIN
optimization on the query and does not examine more rows
in this table for the previous row combination after it
finds one row that matches the LEFT
JOIN criteria. Here is an example of the type
of query that can be optimized this way:
SELECT * FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.id IS NULL;
Assume that t2.id is defined as
NOT NULL. In this case, MySQL scans
t1 and looks up the rows in
t2 using the values of
t1.id. If MySQL finds a matching row
in t2, it knows that
t2.id can never be
NULL, and does not scan through the
rest of the rows in t2 that have the
same id value. In other words, for
each row in t1, MySQL needs to do
only a single lookup in t2,
regardless of how many rows actually match in
t2.
Range checked for each record (index map:
N)
MySQL found no good index to use, but found that some of
indexes might be used after column values from preceding
tables are known. For each row combination in the
preceding tables, MySQL checks whether it is possible to
use a range or
index_merge access
method to retrieve rows. This is not very fast, but is
faster than performing a join with no index at all. The
applicability criteria are as described in
Section 7.3.1.3, “Range Optimization”, and
Section 7.3.1.4, “Index Merge Optimization”, with the
exception that all column values for the preceding table
are known and considered to be constants.
Indexes are numbered beginning with 1, in the same order
as shown by SHOW INDEX
for the table. The index map value
N is a bitmask value that
indicates which indexes are candidates. For example, a
value of 0x19 (binary 11001) means
that indexes 1, 4, and 5 will be considered.
Scanned
N
databases
This indicates how many directory scans the server
performs when processing a query for
INFORMATION_SCHEMA tables, as
described in
Section 7.3.3, “INFORMATION_SCHEMA Optimization”. The
value of N can be 0, 1, or
all.
Select tables optimized away
The query contained only aggregate functions
(MIN(),
MAX()) that were all
resolved using an index, or
COUNT(*) for
MyISAM, and no GROUP
BY clause. The optimizer determined that only
one row should be returned.
Skip_open_table,
Open_frm_only,
Open_trigger_only,
Open_full_table
These values indicate file-opening optimizations that
apply to queries for
INFORMATION_SCHEMA tables, as
described in
Section 7.3.3, “INFORMATION_SCHEMA Optimization”.
Skip_open_table: Table files do
not need to be opened. The information has already
become available within the query by scanning the
database directory.
Open_frm_only: Only the table's
.frm file need be opened.
Open_trigger_only: Only the
table's .TRG file need be
opened.
Open_full_table: The unoptimized
information lookup. The .frm,
.MYD, and
.MYI files must be opened.
unique row not found
For a query such as SELECT ... FROM
, no rows
satisfy the condition for a tbl_nameUNIQUE
index or PRIMARY KEY on the table.
Using filesort
MySQL must do an extra pass to find out how to retrieve
the rows in sorted order. The sort is done by going
through all rows according to the join type and storing
the sort key and pointer to the row for all rows that
match the WHERE clause. The keys then
are sorted and the rows are retrieved in sorted order.
See Section 7.3.1.11, “ORDER BY Optimization”.
Using index
The column information is retrieved from the table using only information in the index tree without having to do an additional seek to read the actual row. This strategy can be used when the query uses only columns that are part of a single index.
For InnoDB tables that have a
user-defined clustered index, that index can be used
even when Using index is absent from
the Extra column. This is the case if
type is
index and
key is PRIMARY.
Using index for group-by
Similar to the Using index table
access method, Using index for
group-by indicates that MySQL found an index
that can be used to retrieve all columns of a
GROUP BY or
DISTINCT query without any extra disk
access to the actual table. Additionally, the index is
used in the most efficient way so that for each group,
only a few index entries are read. For details, see
Section 7.3.1.12, “GROUP BY Optimization”.
Using join buffer
Tables from earlier joins are read in portions into the join buffer, and then their rows are used from the buffer to perform the join with the current table.
Using sort_union(...), Using
union(...), Using
intersect(...)
These indicate how index scans are merged for the
index_merge join
type. See Section 7.3.1.4, “Index Merge Optimization”.
Using temporary
To resolve the query, MySQL needs to create a temporary
table to hold the result. This typically happens if the
query contains GROUP BY and
ORDER BY clauses that list columns
differently.
Using where
A WHERE clause is used to restrict
which rows to match against the next table or send to
the client. Unless you specifically intend to fetch or
examine all rows from the table, you may have something
wrong in your query if the Extra
value is not Using where and the
table join type is
ALL or
index.
Using where with pushed condition
This item applies to
NDBCLUSTER tables
only. It means that MySQL Cluster
is using the Condition Pushdown optimization to improve
the efficiency of a direct comparison between a
nonindexed column and a constant. In such cases, the
condition is “pushed down” to the cluster's
data nodes and is evaluated on all data nodes
simultaneously. This eliminates the need to send
nonmatching rows over the network, and can speed up such
queries by a factor of 5 to 10 times over cases where
Condition Pushdown could be but is not used. For more
information, see
Section 7.3.1.5, “Engine Condition Pushdown Optimization”.
You can get a good indication of how good a join is by taking
the product of the values in the rows column
of the EXPLAIN output. This
should tell you roughly how many rows MySQL must examine to
execute the query. If you restrict queries with the
max_join_size system variable,
this row product also is used to determine which multiple-table
SELECT statements to execute and
which to abort. See Section 7.9.2, “Tuning Server Parameters”.
The following example shows how a multiple-table join can be
optimized progressively based on the information provided by
EXPLAIN.
Suppose that you have the SELECT
statement shown here and that you plan to examine it using
EXPLAIN:
EXPLAIN SELECT tt.TicketNumber, tt.TimeIn,
tt.ProjectReference, tt.EstimatedShipDate,
tt.ActualShipDate, tt.ClientID,
tt.ServiceCodes, tt.RepetitiveID,
tt.CurrentProcess, tt.CurrentDPPerson,
tt.RecordVolume, tt.DPPrinted, et.COUNTRY,
et_1.COUNTRY, do.CUSTNAME
FROM tt, et, et AS et_1, do
WHERE tt.SubmitTime IS NULL
AND tt.ActualPC = et.EMPLOYID
AND tt.AssignedPC = et_1.EMPLOYID
AND tt.ClientID = do.CUSTNMBR;
For this example, make the following assumptions:
The columns being compared have been declared as follows.
| Table | Column | Data Type |
|---|---|---|
tt | ActualPC | CHAR(10) |
tt | AssignedPC | CHAR(10) |
tt | ClientID | CHAR(10) |
et | EMPLOYID | CHAR(15) |
do | CUSTNMBR | CHAR(15) |
The tables have the following indexes.
| Table | Index |
|---|---|
tt | ActualPC |
tt | AssignedPC |
tt | ClientID |
et | EMPLOYID (primary key) |
do | CUSTNMBR (primary key) |
The tt.ActualPC values are not evenly
distributed.
Initially, before any optimizations have been performed, the
EXPLAIN statement produces the
following information:
table type possible_keys key key_len ref rows Extra
et ALL PRIMARY NULL NULL NULL 74
do ALL PRIMARY NULL NULL NULL 2135
et_1 ALL PRIMARY NULL NULL NULL 74
tt ALL AssignedPC, NULL NULL NULL 3872
ClientID,
ActualPC
Range checked for each record (index map: 0x23)
Because type is
ALL for each table, this
output indicates that MySQL is generating a Cartesian product of
all the tables; that is, every combination of rows. This takes
quite a long time, because the product of the number of rows in
each table must be examined. For the case at hand, this product
is 74 × 2135 × 74 × 3872 = 45,268,558,720
rows. If the tables were bigger, you can only imagine how long
it would take.
One problem here is that MySQL can use indexes on columns more
efficiently if they are declared as the same type and size. In
this context, VARCHAR and
CHAR are considered the same if
they are declared as the same size.
tt.ActualPC is declared as
CHAR(10) and et.EMPLOYID
is CHAR(15), so there is a length mismatch.
To fix this disparity between column lengths, use
ALTER TABLE to lengthen
ActualPC from 10 characters to 15 characters:
mysql> ALTER TABLE tt MODIFY ActualPC VARCHAR(15);
Now tt.ActualPC and
et.EMPLOYID are both
VARCHAR(15). Executing the
EXPLAIN statement again produces
this result:
table type possible_keys key key_len ref rows Extra
tt ALL AssignedPC, NULL NULL NULL 3872 Using
ClientID, where
ActualPC
do ALL PRIMARY NULL NULL NULL 2135
Range checked for each record (index map: 0x1)
et_1 ALL PRIMARY NULL NULL NULL 74
Range checked for each record (index map: 0x1)
et eq_ref PRIMARY PRIMARY 15 tt.ActualPC 1
This is not perfect, but is much better: The product of the
rows values is less by a factor of 74. This
version executes in a couple of seconds.
A second alteration can be made to eliminate the column length
mismatches for the tt.AssignedPC =
et_1.EMPLOYID and tt.ClientID =
do.CUSTNMBR comparisons:
mysql>ALTER TABLE tt MODIFY AssignedPC VARCHAR(15),->MODIFY ClientID VARCHAR(15);
After that modification, EXPLAIN
produces the output shown here:
table type possible_keys key key_len ref rows Extra
et ALL PRIMARY NULL NULL NULL 74
tt ref AssignedPC, ActualPC 15 et.EMPLOYID 52 Using
ClientID, where
ActualPC
et_1 eq_ref PRIMARY PRIMARY 15 tt.AssignedPC 1
do eq_ref PRIMARY PRIMARY 15 tt.ClientID 1
At this point, the query is optimized almost as well as
possible. The remaining problem is that, by default, MySQL
assumes that values in the tt.ActualPC column
are evenly distributed, and that is not the case for the
tt table. Fortunately, it is easy to tell
MySQL to analyze the key distribution:
mysql> ANALYZE TABLE tt;
With the additional index information, the join is perfect and
EXPLAIN produces this result:
table type possible_keys key key_len ref rows Extra
tt ALL AssignedPC NULL NULL NULL 3872 Using
ClientID, where
ActualPC
et eq_ref PRIMARY PRIMARY 15 tt.ActualPC 1
et_1 eq_ref PRIMARY PRIMARY 15 tt.AssignedPC 1
do eq_ref PRIMARY PRIMARY 15 tt.ClientID 1
Note that the rows column in the output from
EXPLAIN is an educated guess from
the MySQL join optimizer. You should check whether the numbers
are even close to the truth by comparing the
rows product with the actual number of rows
that the query returns. If the numbers are quite different, you
might get better performance by using
STRAIGHT_JOIN in your
SELECT statement and trying to
list the tables in a different order in the
FROM clause.
It is possible in some cases to execute statements that modify
data when EXPLAIN
SELECT is used with a subquery; for more information,
see Section 12.2.9.8, “Subqueries in the FROM Clause”.
In most cases, you can estimate query performance by counting
disk seeks. For small tables, you can usually find a row in one
disk seek (because the index is probably cached). For bigger
tables, you can estimate that, using B-tree indexes, you need
this many seeks to find a row:
log(.
row_count) /
log(index_block_length / 3 * 2 /
(index_length +
data_pointer_length)) + 1
In MySQL, an index block is usually 1,024 bytes and the data
pointer is usually four bytes. For a 500,000-row table with a
key value length of three bytes (the size of
MEDIUMINT), the formula indicates
log(500,000)/log(1024/3*2/(3+4)) + 1 =
4 seeks.
This index would require storage of about 500,000 * 7 * 3/2 = 5.2MB (assuming a typical index buffer fill ratio of 2/3), so you probably have much of the index in memory and so need only one or two calls to read data to find the row.
For writes, however, you need four seek requests to find where to place a new index value and normally two seeks to update the index and write the row.
Note that the preceding discussion does not mean that your
application performance slowly degenerates by log
N. As long as everything is cached by
the OS or the MySQL server, things become only marginally slower
as the table gets bigger. After the data gets too big to be
cached, things start to go much slower until your applications
are bound only by disk seeks (which increase by log
N). To avoid this, increase the key
cache size as the data grows. For MyISAM
tables, the key cache size is controlled by the
key_buffer_size system
variable. See Section 7.9.2, “Tuning Server Parameters”.
SELECT StatementsWHERE Clause OptimizationIS NULL OptimizationLEFT JOIN and RIGHT JOIN
OptimizationORDER BY OptimizationGROUP BY OptimizationDISTINCT OptimizationIN/=ANY SubqueriesLIMIT Optimization
First, one factor affects all statements: The more complex your
permissions setup, the more overhead you have. Using simpler
permissions when you issue GRANT
statements enables MySQL to reduce permission-checking overhead
when clients execute statements. For example, if you do not
grant any table-level or column-level privileges, the server
need not ever check the contents of the
tables_priv and
columns_priv tables. Similarly, if you place
no resource limits on any accounts, the server does not have to
perform resource counting. If you have a very high
statement-processing load, it may be worth the time to use a
simplified grant structure to reduce permission-checking
overhead.
If your problem is with a specific MySQL expression or function,
you can perform a timing test by invoking the
BENCHMARK() function using the
mysql client program. Its syntax is
BENCHMARK(.
The return value is always zero, but mysql
prints a line displaying approximately how long the statement
took to execute. For example:
loop_count,expression)
mysql> SELECT BENCHMARK(1000000,1+1);
+------------------------+
| BENCHMARK(1000000,1+1) |
+------------------------+
| 0 |
+------------------------+
1 row in set (0.32 sec)
This result was obtained on a Pentium II 400MHz system. It shows that MySQL can execute 1,000,000 simple addition expressions in 0.32 seconds on that system.
All MySQL functions should be highly optimized, but there may be
some exceptions. BENCHMARK() is
an excellent tool for finding out if some function is a problem
for your queries.
In general, when you want to make a slow SELECT ...
WHERE query faster, the first thing to check is
whether you can add an index. All references between different
tables should usually be done with indexes. You can use the
EXPLAIN statement to determine
which indexes are used for a
SELECT. See
Section 7.2.1, “Optimizing Queries with EXPLAIN”, and
Section 7.5.3, “How MySQL Uses Indexes”.
Some general tips for speeding up queries on
MyISAM tables:
To help MySQL better optimize queries, use
ANALYZE TABLE or run
myisamchk --analyze on a table after it
has been loaded with data. This updates a value for each
index part that indicates the average number of rows that
have the same value. (For unique indexes, this is always
1.) MySQL uses this to decide which index to choose when
you join two tables based on a nonconstant expression. You
can check the result from the table analysis by using
SHOW INDEX FROM
and
examining the tbl_nameCardinality value.
myisamchk --description --verbose shows
index distribution information.
To sort an index and data according to an index, use myisamchk --sort-index --sort-records=1 (assuming that you want to sort on index 1). This is a good way to make queries faster if you have a unique index from which you want to read all rows in order according to the index. The first time you sort a large table this way, it may take a long time.
This section discusses optimizations that can be made for
processing WHERE clauses. The examples use
SELECT statements, but the same
optimizations apply for WHERE clauses in
DELETE and
UPDATE statements.
Work on the MySQL optimizer is ongoing, so this section is incomplete. MySQL performs a great many optimizations, not all of which are documented here.
Some of the optimizations performed by MySQL follow:
Removal of unnecessary parentheses:
((a AND b) AND c OR (((a AND b) AND (c AND d)))) -> (a AND b AND c) OR (a AND b AND c AND d)
Constant folding:
(a<b AND b=c) AND a=5 -> b>5 AND b=c AND a=5
Constant condition removal (needed because of constant folding):
(B>=5 AND B=5) OR (B=6 AND 5=5) OR (B=7 AND 5=6) -> B=5 OR B=6
Constant expressions used by indexes are evaluated only once.
COUNT(*) on a single table
without a WHERE is retrieved directly
from the table information for MyISAM
and MEMORY tables. This is also done
for any NOT NULL expression when used
with only one table.
Early detection of invalid constant expressions. MySQL
quickly detects that some
SELECT statements are
impossible and returns no rows.
HAVING is merged with
WHERE if you do not use GROUP
BY or aggregate functions
(COUNT(),
MIN(), and so on).
For each table in a join, a simpler
WHERE is constructed to get a fast
WHERE evaluation for the table and also
to skip rows as soon as possible.
All constant tables are read first before any other tables in the query. A constant table is any of the following:
An empty table or a table with one row.
A table that is used with a WHERE
clause on a PRIMARY KEY or a
UNIQUE index, where all index parts
are compared to constant expressions and are defined
as NOT NULL.
All of the following tables are used as constant tables:
SELECT * FROM t WHEREprimary_key=1; SELECT * FROM t1,t2 WHERE t1.primary_key=1 AND t2.primary_key=t1.id;
The best join combination for joining the tables is found
by trying all possibilities. If all columns in
ORDER BY and GROUP
BY clauses come from the same table, that table
is preferred first when joining.
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.
If you use the SQL_SMALL_RESULT option,
MySQL uses an in-memory temporary table.
Each table index is queried, and the best index is used unless the optimizer believes that it is more efficient to use a table scan. At one time, a scan was used based on whether the best index spanned more than 30% of the table, but a fixed percentage no longer determines the choice between using an index or a scan. The optimizer now is more complex and bases its estimate on additional factors such as table size, number of rows, and I/O block size.
In some cases, MySQL can read rows from the index without even consulting the data file. If all columns used from the index are numeric, only the index tree is used to resolve the query.
Before each row is output, those that do not match the
HAVING clause are skipped.
Some examples of queries that are very fast:
SELECT COUNT(*) FROMtbl_name; SELECT MIN(key_part1),MAX(key_part1) FROMtbl_name; SELECT MAX(key_part2) FROMtbl_nameWHEREkey_part1=constant; SELECT ... FROMtbl_nameORDER BYkey_part1,key_part2,... LIMIT 10; SELECT ... FROMtbl_nameORDER BYkey_part1DESC,key_part2DESC, ... LIMIT 10;
MySQL resolves the following queries using only the index tree, assuming that the indexed columns are numeric:
SELECTkey_part1,key_part2FROMtbl_nameWHEREkey_part1=val; SELECT COUNT(*) FROMtbl_nameWHEREkey_part1=val1ANDkey_part2=val2; SELECTkey_part2FROMtbl_nameGROUP BYkey_part1;
The following queries use indexing to retrieve the rows in sorted order without a separate sorting pass:
SELECT ... FROMtbl_nameORDER BYkey_part1,key_part2,... ; SELECT ... FROMtbl_nameORDER BYkey_part1DESC,key_part2DESC, ... ;
The range access method
uses a single index to retrieve a subset of table rows that
are contained within one or several index value intervals. It
can be used for a single-part or multiple-part index. The
following sections give a detailed description of how
intervals are extracted from the WHERE
clause.
For a single-part index, index value intervals can be
conveniently represented by corresponding conditions in the
WHERE clause, so we speak of
range conditions rather than
“intervals.”
The definition of a range condition for a single-part index is as follows:
For both BTREE and
HASH indexes, comparison of a key
part with a constant value is a range condition when
using the
=,
<=>,
IN(),
IS NULL, or
IS NOT NULL operators.
Additionally, for BTREE indexes,
comparison of a key part with a constant value is a
range condition when using the
>,
<,
>=,
<=,
BETWEEN,
!=,
or
<>
operators, or LIKE
comparisons if the argument to
LIKE is a constant string
that does not start with a wildcard character.
For all types of indexes, multiple range conditions
combined with OR or
AND form a range condition.
“Constant value” in the preceding descriptions means one of the following:
Here are some examples of queries with range conditions in
the WHERE clause:
SELECT * FROM t1 WHEREkey_col> 1 ANDkey_col< 10; SELECT * FROM t1 WHEREkey_col= 1 ORkey_colIN (15,18,20); SELECT * FROM t1 WHEREkey_colLIKE 'ab%' ORkey_colBETWEEN 'bar' AND 'foo';
Note that some nonconstant values may be converted to constants during the constant propagation phase.
MySQL tries to extract range conditions from the
WHERE clause for each of the possible
indexes. During the extraction process, conditions that
cannot be used for constructing the range condition are
dropped, conditions that produce overlapping ranges are
combined, and conditions that produce empty ranges are
removed.
Consider the following statement, where
key1 is an indexed column and
nonkey is not indexed:
SELECT * FROM t1 WHERE (key1 < 'abc' AND (key1 LIKE 'abcde%' OR key1 LIKE '%b')) OR (key1 < 'bar' AND nonkey = 4) OR (key1 < 'uux' AND key1 > 'z');
The extraction process for key key1 is as
follows:
Start with original WHERE clause:
(key1 < 'abc' AND (key1 LIKE 'abcde%' OR key1 LIKE '%b')) OR (key1 < 'bar' AND nonkey = 4) OR (key1 < 'uux' AND key1 > 'z')
Remove nonkey = 4 and key1
LIKE '%b' because they cannot be used for a
range scan. The correct way to remove them is to replace
them with TRUE, so that we do not
miss any matching rows when doing the range scan. Having
replaced them with TRUE, we get:
(key1 < 'abc' AND (key1 LIKE 'abcde%' OR TRUE)) OR (key1 < 'bar' AND TRUE) OR (key1 < 'uux' AND key1 > 'z')
Collapse conditions that are always true or false:
(key1 LIKE 'abcde%' OR TRUE) is
always true
(key1 < 'uux' AND key1 >
'z') is always false
Replacing these conditions with constants, we get:
(key1 < 'abc' AND TRUE) OR (key1 < 'bar' AND TRUE) OR (FALSE)
Removing unnecessary TRUE and
FALSE constants, we obtain:
(key1 < 'abc') OR (key1 < 'bar')
Combining overlapping intervals into one yields the final condition to be used for the range scan:
(key1 < 'bar')
In general (and as demonstrated by the preceding example),
the condition used for a range scan is less restrictive than
the WHERE clause. MySQL performs an
additional check to filter out rows that satisfy the range
condition but not the full WHERE clause.
The range condition extraction algorithm can handle nested
AND/OR
constructs of arbitrary depth, and its output does not
depend on the order in which conditions appear in
WHERE clause.
Currently, MySQL does not support merging multiple ranges
for the range access
method for spatial indexes. To work around this limitation,
you can use a UNION with
identical SELECT statements,
except that you put each spatial predicate in a different
SELECT.
Range conditions on a multiple-part index are an extension of range conditions for a single-part index. A range condition on a multiple-part index restricts index rows to lie within one or several key tuple intervals. Key tuple intervals are defined over a set of key tuples, using ordering from the index.
For example, consider a multiple-part index defined as
key1(, and the
following set of key tuples listed in key order:
key_part1,
key_part2,
key_part3)
key_part1key_part2key_part3NULL 1 'abc' NULL 1 'xyz' NULL 2 'foo' 1 1 'abc' 1 1 'xyz' 1 2 'abc' 2 1 'aaa'
The condition defines this interval:
key_part1
= 1
(1,-inf,-inf) <= (key_part1,key_part2,key_part3) < (1,+inf,+inf)
The interval covers the 4th, 5th, and 6th tuples in the preceding data set and can be used by the range access method.
By contrast, the condition
does not define a single interval and cannot
be used by the range access method.
key_part3 =
'abc'
The following descriptions indicate how range conditions work for multiple-part indexes in greater detail.
For HASH indexes, each interval
containing identical values can be used. This means that
the interval can be produced only for conditions in the
following form:
key_part1cmpconst1ANDkey_part2cmpconst2AND ... ANDkey_partNcmpconstN;
Here, const1,
const2, … are
constants, cmp is one of the
=,
<=>,
or IS NULL comparison
operators, and the conditions cover all index parts.
(That is, there are N
conditions, one for each part of an
N-part index.) For example,
the following is a range condition for a three-part
HASH index:
key_part1= 1 ANDkey_part2IS NULL ANDkey_part3= 'foo'
For the definition of what is considered to be a constant, see Section 7.3.1.3.1, “The Range Access Method for Single-Part Indexes”.
For a BTREE index, an interval might
be usable for conditions combined with
AND, where each condition
compares a key part with a constant value using
=,
<=>,
IS NULL,
>,
<,
>=,
<=,
!=,
<>,
BETWEEN, or
LIKE
' (where
pattern''
does not start with a wildcard). An interval can be used
as long as it is possible to determine a single key
tuple containing all rows that match the condition (or
two intervals if
pattern'<>
or !=
is used). For example, for this condition:
key_part1= 'foo' ANDkey_part2>= 10 ANDkey_part3> 10
The single interval is:
('foo',10,10) < (key_part1,key_part2,key_part3) < ('foo',+inf,+inf)
It is possible that the created interval contains more
rows than the initial condition. For example, the
preceding interval includes the value ('foo',
11, 0), which does not satisfy the original
condition.
If conditions that cover sets of rows contained within
intervals are combined with
OR, they form a condition
that covers a set of rows contained within the union of
their intervals. If the conditions are combined with
AND, they form a condition
that covers a set of rows contained within the
intersection of their intervals. For example, for this
condition on a two-part index:
(key_part1= 1 ANDkey_part2< 2) OR (key_part1> 5)
The intervals are:
(1,-inf) < (key_part1,key_part2) < (1,2) (5,-inf) < (key_part1,key_part2)
In this example, the interval on the first line uses one
key part for the left bound and two key parts for the
right bound. The interval on the second line uses only
one key part. The key_len column in
the EXPLAIN output
indicates the maximum length of the key prefix used.
In some cases, key_len may indicate
that a key part was used, but that might be not what you
would expect. Suppose that
key_part1 and
key_part2 can be
NULL. Then the
key_len column displays two key part
lengths for the following condition:
key_part1>= 1 ANDkey_part2< 2
But, in fact, the condition is converted to this:
key_part1>= 1 ANDkey_part2IS NOT NULL
Section 7.3.1.3.1, “The Range Access Method for Single-Part Indexes”, describes how optimizations are performed to combine or eliminate intervals for range conditions on a single-part index. Analogous steps are performed for range conditions on multiple-part indexes.
The Index Merge method is used to
retrieve rows with several
range scans and to merge
their results into one. The merge can produce unions,
intersections, or unions-of-intersections of its underlying
scans. This access method merges index scans from a single
table; it does not merge scans across multiple tables.
In EXPLAIN output, the Index
Merge method appears as
index_merge in the
type column. In this case, the
key column contains a list of indexes used,
and key_len contains a list of the longest
key parts for those indexes.
Examples:
SELECT * FROMtbl_nameWHEREkey1= 10 ORkey2= 20; SELECT * FROMtbl_nameWHERE (key1= 10 ORkey2= 20) ANDnon_key=30; SELECT * FROM t1, t2 WHERE (t1.key1IN (1,2) OR t1.key2LIKE 'value%') AND t2.key1=t1.some_col; SELECT * FROM t1, t2 WHERE t1.key1=1 AND (t2.key1=t1.some_colOR t2.key2=t1.some_col2);
The Index Merge method has several access algorithms (seen in
the Extra field of
EXPLAIN output):
Using intersect(...)
Using union(...)
Using sort_union(...)
The following sections describe these methods in greater detail.
The Index Merge optimization algorithm has the following known deficiencies:
If a range scan is possible on some key, the optimizer will not consider using Index Merge Union or Index Merge Sort-Union algorithms. For example, consider this query:
SELECT * FROM t1 WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30;
For this query, two plans are possible:
An Index Merge scan using the (goodkey1 <
10 OR goodkey2 < 20) condition.
A range scan using the badkey <
30 condition.
However, the optimizer considers only the second plan.
If your query has a complex WHERE
clause with deep
AND/OR
nesting and MySQL doesn't choose the optimal plan, try
distributing terms using the following identity laws:
(xANDy) ORz= (xORz) AND (yORz) (xORy) ANDz= (xANDz) OR (yANDz)
Index Merge is not applicable to full-text indexes. We plan to extend it to cover these in a future MySQL release.
The choice between different possible variants of the Index Merge access method and other access methods is based on cost estimates of various available options.
This access algorithm can be employed when a
WHERE clause was converted to several
range conditions on different keys combined with
AND, and each condition is one
of the following:
In this form, where the index has exactly
N parts (that is, all index
parts are covered):
key_part1=const1ANDkey_part2=const2... ANDkey_partN=constN
Any range condition over a primary key of an
InnoDB table.
Examples:
SELECT * FROMinnodb_tableWHEREprimary_key< 10 ANDkey_col1=20; SELECT * FROMtbl_nameWHERE (key1_part1=1 ANDkey1_part2=2) ANDkey2=2;
The Index Merge intersection algorithm performs simultaneous scans on all used indexes and produces the intersection of row sequences that it receives from the merged index scans.
If all columns used in the query are covered by the used
indexes, full table rows are not retrieved
(EXPLAIN output contains
Using index in Extra
field in this case). Here is an example of such a query:
SELECT COUNT(*) FROM t1 WHERE key1=1 AND key2=1;
If the used indexes don't cover all columns used in the query, full rows are retrieved only when the range conditions for all used keys are satisfied.
If one of the merged conditions is a condition over a
primary key of an InnoDB table, it is not
used for row retrieval, but is used to filter out rows
retrieved using other conditions.
The applicability criteria for this algorithm are similar to
those for the Index Merge method intersection algorithm. The
algorithm can be employed when the table's
WHERE clause was converted to several
range conditions on different keys combined with
OR, and each condition is one
of the following:
In this form, where the index has exactly
N parts (that is, all index
parts are covered):
key_part1=const1ANDkey_part2=const2... ANDkey_partN=constN
Any range condition over a primary key of an
InnoDB table.
A condition for which the Index Merge method intersection algorithm is applicable.
Examples:
SELECT * FROM t1 WHEREkey1=1 ORkey2=2 ORkey3=3; SELECT * FROMinnodb_tableWHERE (key1=1 ANDkey2=2) OR (key3='foo' ANDkey4='bar') ANDkey5=5;
This access algorithm is employed when the
WHERE clause was converted to several
range conditions combined by
OR, but for which the Index
Merge method union algorithm is not applicable.
Examples:
SELECT * FROMtbl_nameWHEREkey_col1< 10 ORkey_col2< 20; SELECT * FROMtbl_nameWHERE (key_col1> 10 ORkey_col2= 20) ANDnonkey_col=30;
The difference between the sort-union algorithm and the union algorithm is that the sort-union algorithm must first fetch row IDs for all rows and sort them before returning any rows.
This optimization improves the efficiency of direct
comparisons between a nonindexed column and a constant. In
such cases, the condition is “pushed down” to the
storage engine for evaluation. This optimization can be used
only by the NDBCLUSTER storage
engine.
For MySQL Cluster, this optimization can eliminate the need to send nonmatching rows over the network between the cluster's data nodes and the MySQL Server that issued the query, and can speed up queries where it is used by a factor of 5 to 10 times over cases where condition pushdown could be but is not used.
Suppose that a MySQL Cluster table is defined as follows:
CREATE TABLE t1 (
a INT,
b INT,
KEY(a)
) ENGINE=NDBCLUSTER;
Condition pushdown can be used with queries such as the one shown here, which includes a comparison between a nonindexed column and a constant:
SELECT a, b FROM t1 WHERE b = 10;
The use of condition pushdown can be seen in the output of
EXPLAIN:
mysql> EXPLAIN SELECT a,b FROM t1 WHERE b = 10\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t1
type: ALL
possible_keys: NULL
key: NULL
key_len: NULL
ref: NULL
rows: 10
Extra: Using where with pushed condition
However, condition pushdown cannot be used with either of these two queries:
SELECT a,b FROM t1 WHERE a = 10; SELECT a,b FROM t1 WHERE b + 1 = 10;
Condition pushdown is not applicable to the first query
because an index exists on column a. (An
index access method would be more efficient and so would be
chosen in preference to condition pushdown.) Condition
pushdown cannot be employed for the second query because the
comparison involving the nonindexed column
b is indirect. (However, condition pushdown
could be applied if you were to reduce b + 1 =
10 to b = 9 in the
WHERE clause.)
Condition pushdown may also be employed when an indexed column
is compared with a constant using a > or
< operator:
mysql> EXPLAIN SELECT a, b FROM t1 WHERE a < 2\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t1
type: range
possible_keys: a
key: a
key_len: 5
ref: NULL
rows: 2
Extra: Using where with pushed condition
Other supported comparisons for condition pushdown include the following:
column [NOT] LIKE
pattern
pattern must be a string
literal containing the pattern to be matched; for
syntax, see
Section 11.5.1, “String Comparison Functions”.
column IS [NOT]
NULL
column IN
(value_list)
Each item in the value_list
must be a constant, literal value.
column BETWEEN
constant1 AND
constant2
constant1 and
constant2 must each be a
constant, literal value.
In all of the cases in the preceding list, it is possible for the condition to be converted into the form of one or more direct comparisons between a column and a constant.
Engine condition pushdown is enabled by default. To disable it
at server startup, set the
engine_condition_pushdown
system variable. For example, in a my.cnf
file, use these lines:
[mysqld] engine_condition_pushdown=0
At runtime, disable condition pushdown with either of the following statements:
SET engine_condition_pushdown=OFF;
SET engine_condition_pushdown=0;
Limitations. Engine condition pushdown is subject to the following limitations:
Condition pushdown is supported only by the
NDBCLUSTER storage
engine.
Columns may be compared with constants only; however, this includes expressions which evaluate to constant values.
Columns used in comparisons cannot be of any of the
BLOB or
TEXT types.
A string value to be compared with a column must use the same collation as the column.
Joins are not directly supported; conditions involving
multiple tables are pushed separately where possible.
Use EXPLAIN
EXTENDED to determine which conditions are
actually pushed down.
MySQL can perform the same optimization on
col_name IS
NULL that it can use for
col_name =
constant_value. For example, MySQL
can use indexes and ranges to search for
NULL with IS
NULL.
Examples:
SELECT * FROMtbl_nameWHEREkey_colIS NULL; SELECT * FROMtbl_nameWHEREkey_col<=> NULL; SELECT * FROMtbl_nameWHEREkey_col=const1ORkey_col=const2ORkey_colIS NULL;
If a WHERE clause includes a
col_name IS
NULL condition for a column that is declared as
NOT NULL, that expression is optimized
away. This optimization does not occur in cases when the
column might produce NULL anyway; for
example, if it comes from a table on the right side of a
LEFT JOIN.
MySQL can also optimize the combination
, a form
that is common in resolved subqueries.
col_name =
expr OR
col_name IS NULLEXPLAIN shows
ref_or_null when this
optimization is used.
This optimization can handle one IS
NULL for any key part.
Some examples of queries that are optimized, assuming that
there is an index on columns a and
b of table t2:
SELECT * FROM t1 WHERE t1.a=expr OR t1.a IS NULL;
SELECT * FROM t1, t2 WHERE t1.a=t2.a OR t2.a IS NULL;
SELECT * FROM t1, t2
WHERE (t1.a=t2.a OR t2.a IS NULL) AND t2.b=t1.b;
SELECT * FROM t1, t2
WHERE t1.a=t2.a AND (t2.b=t1.b OR t2.b IS NULL);
SELECT * FROM t1, t2
WHERE (t1.a=t2.a AND t2.a IS NULL AND ...)
OR (t1.a=t2.a AND t2.a IS NULL AND ...);
ref_or_null works by first
doing a read on the reference key, and then a separate search
for rows with a NULL key value.
Note that the optimization can handle only one
IS NULL level. In the following
query, MySQL uses key lookups only on the expression
(t1.a=t2.a AND t2.a IS NULL) and is not
able to use the key part on b:
SELECT * FROM t1, t2 WHERE (t1.a=t2.a AND t2.a IS NULL) OR (t1.b=t2.b AND t2.b IS NULL);
MySQL implements an as
follows:
A LEFT
JOIN B join_condition
Table B is set to depend on
table A and all tables on which
A depends.
Table A is set to depend on all
tables (except B) that are used
in the LEFT JOIN condition.
The LEFT JOIN condition is used to
decide how to retrieve rows from table
B. (In other words, any
condition in the WHERE clause is not
used.)
All standard join optimizations are performed, with the exception that a table is always read after all tables on which it depends. If there is a circular dependence, MySQL issues an error.
All standard WHERE optimizations are
performed.
If there is a row in A that
matches the WHERE clause, but there is
no row in B that matches the
ON condition, an extra
B row is generated with all
columns set to NULL.
If you use LEFT JOIN to find rows that
do not exist in some table and you have the following
test: in the col_name IS
NULLWHERE part, where
col_name is a column that is
declared as NOT NULL, MySQL stops
searching for more rows (for a particular key combination)
after it has found one row that matches the LEFT
JOIN condition.
The implementation of RIGHT JOIN is
analogous to that of LEFT JOIN with the
roles of the tables reversed.
The join optimizer calculates the order in which tables should
be joined. The table read order forced by LEFT
JOIN or STRAIGHT_JOIN helps the
join optimizer do its work much more quickly, because there
are fewer table permutations to check. Note that this means
that if you do a query of the following type, MySQL does a
full scan on b because the LEFT
JOIN forces it to be read before
d:
SELECT * FROM a JOIN b LEFT JOIN c ON (c.key=a.key) LEFT JOIN d ON (d.key=a.key) WHERE b.key=d.key;
The fix in this case is reverse the order in which
a and b are listed in
the FROM clause:
SELECT * FROM b JOIN a LEFT JOIN c ON (c.key=a.key) LEFT JOIN d ON (d.key=a.key) WHERE b.key=d.key;
For a LEFT JOIN, if the
WHERE condition is always false for the
generated NULL row, the LEFT
JOIN is changed to a normal join. For example, the
WHERE clause would be false in the
following query if t2.column1 were
NULL:
SELECT * FROM t1 LEFT JOIN t2 ON (column1) WHERE t2.column2=5;
Therefore, it is safe to convert the query to a normal join:
SELECT * FROM t1, t2 WHERE t2.column2=5 AND t1.column1=t2.column1;
This can be made faster because MySQL can use table
t2 before table t1 if
doing so would result in a better query plan. To provide a
hint about the table join order, use
STRAIGHT_JOIN. (See
Section 12.2.8, “SELECT Syntax”.)
MySQL executes joins between tables using a nested-loop algorithm or variations on it.
Nested-Loop Join Algorithm
A simple nested-loop join (NLJ) algorithm reads rows from the first table in a loop one at a time, passing each row to a nested loop that processes the next table in the join. This process is repeated as many times as there remain tables to be joined.
Assume that a join between three tables t1,
t2, and t3 is to be
executed using the following join types:
Table Join Type t1 range t2 ref t3 ALL
If a simple NLJ algorithm is used, the join would be processed like this:
for each row in t1 matching range {
for each row in t2 matching reference key {
for each row in t3 {
if row satisfies join conditions,
send to client
}
}
}
Because the NLJ algorithm passes rows one at a time from outer loops to inner loops, tables processed in the inner loops typically are read many times.
Block Nested-Loop Join Algorithm
A Block Nested-Loop (BNL) Join algorithm uses buffering of rows read in outer loops to reduce the number of times that tables in inner loops must be read. For example, if 10 rows are read into a buffer and the buffer is passed to the next inner loop, each row read in the inner loop can be compared against all 10 rows in the buffer. The reduces the number of times the inner table must be read by an order of magnitude.
MySQL uses join buffering under these conditions:
The join_buffer_size
system variable determines the size of each join buffer.
Join buffering can be used when the join is of type
ALL or
index (in other words,
when no possible keys can be used, and a full scan is
done, of either the data or index rows, respectively), or
range.
One buffer is allocated for each join that can be buffered, so a given query might be processed using multiple join buffers.
A join buffer is never allocated for the first nonconst
table, even if it would be of type
ALL or
index.
A join buffer is allocated prior to executing the join and freed after the query is done.
Only columns of interest to the join are stored in the join buffer, not whole rows.
For the example join described previously for the NLJ algorithm (without buffering), the join would be done as follow using join buffering:
for each row in t1 matching range {
for each row in t2 matching reference key {
store used columns from t1, t2 in join buffer
if buffer is full {
for each row in t3 {
for each t1, t2 combination in join buffer {
if row satisfies join conditions,
send to client
}
}
empty buffer
}
}
}
if buffer is not empty {
for each row in t3 {
for each t1, t2 combination in join buffer {
if row satisfies join conditions,
send to client
}
}
}
If S is the size of each stored
t1, t2 combination is
the join buffer and C is the number
of combinations in the buffer, the number of times table
t3 is scanned is:
(S*C)/join_buffer_size + 1
One implication is that the number of t3
scans decreases as the value of
join_buffer_size increases,
up to the point when
join_buffer_size is large
enough to hold all previous row combinations. At that point,
there is no speed to be gained by making it larger.
The syntax for expressing joins permits nested joins. The
following discussion refers to the join syntax described in
Section 12.2.8.1, “JOIN Syntax”.
The syntax of table_factor is
extended in comparison with the SQL Standard. The latter
accepts only table_reference, not a
list of them inside a pair of parentheses. This is a
conservative extension if we consider each comma in a list of
table_reference items as equivalent
to an inner join. For example:
SELECT * FROM t1 LEFT JOIN (t2, t3, t4)
ON (t2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c)
is equivalent to:
SELECT * FROM t1 LEFT JOIN (t2 CROSS JOIN t3 CROSS JOIN t4)
ON (t2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c)
In MySQL, CROSS JOIN is a syntactic
equivalent to INNER JOIN (they can replace
each other). In standard SQL, they are not equivalent.
INNER JOIN is used with an
ON clause; CROSS JOIN is
used otherwise.
In general, parentheses can be ignored in join expressions containing only inner join operations. After removing parentheses and grouping operations to the left, the join expression:
t1 LEFT JOIN (t2 LEFT JOIN t3 ON t2.b=t3.b OR t2.b IS NULL) ON t1.a=t2.a
transforms into the expression:
(t1 LEFT JOIN t2 ON t1.a=t2.a) LEFT JOIN t3
ON t2.b=t3.b OR t2.b IS NULL
Yet, the two expressions are not equivalent. To see this,
suppose that the tables t1,
t2, and t3 have the
following state:
Table t1 contains rows
(1), (2)
Table t2 contains row
(1,101)
Table t3 contains row
(101)
In this case, the first expression returns a result set
including the rows (1,1,101,101),
(2,NULL,NULL,NULL), whereas the second
expression returns the rows (1,1,101,101),
(2,NULL,NULL,101):
mysql>SELECT *->FROM t1->LEFT JOIN->(t2 LEFT JOIN t3 ON t2.b=t3.b OR t2.b IS NULL)->ON t1.a=t2.a;+------+------+------+------+ | a | a | b | b | +------+------+------+------+ | 1 | 1 | 101 | 101 | | 2 | NULL | NULL | NULL | +------+------+------+------+ mysql>SELECT *->FROM (t1 LEFT JOIN t2 ON t1.a=t2.a)->LEFT JOIN t3->ON t2.b=t3.b OR t2.b IS NULL;+------+------+------+------+ | a | a | b | b | +------+------+------+------+ | 1 | 1 | 101 | 101 | | 2 | NULL | NULL | 101 | +------+------+------+------+
In the following example, an outer join operation is used together with an inner join operation:
t1 LEFT JOIN (t2, t3) ON t1.a=t2.a
That expression cannot be transformed into the following expression:
t1 LEFT JOIN t2 ON t1.a=t2.a, t3.
For the given table states, the two expressions return different sets of rows:
mysql>SELECT *->FROM t1 LEFT JOIN (t2, t3) ON t1.a=t2.a;+------+------+------+------+ | a | a | b | b | +------+------+------+------+ | 1 | 1 | 101 | 101 | | 2 | NULL | NULL | NULL | +------+------+------+------+ mysql>SELECT *->FROM t1 LEFT JOIN t2 ON t1.a=t2.a, t3;+------+------+------+------+ | a | a | b | b | +------+------+------+------+ | 1 | 1 | 101 | 101 | | 2 | NULL | NULL | 101 | +------+------+------+------+
Therefore, if we omit parentheses in a join expression with outer join operators, we might change the result set for the original expression.
More exactly, we cannot ignore parentheses in the right operand of the left outer join operation and in the left operand of a right join operation. In other words, we cannot ignore parentheses for the inner table expressions of outer join operations. Parentheses for the other operand (operand for the outer table) can be ignored.
The following expression:
(t1,t2) LEFT JOIN t3 ON P(t2.b,t3.b)
is equivalent to this expression:
t1, t2 LEFT JOIN t3 ON P(t2.b,t3.b)
for any tables t1,t2,t3 and any condition
P over attributes t2.b
and t3.b.
Whenever the order of execution of the join operations in a
join expression (join_table) is not
from left to right, we talk about nested joins. Consider the
following queries:
SELECT * FROM t1 LEFT JOIN (t2 LEFT JOIN t3 ON t2.b=t3.b) ON t1.a=t2.a WHERE t1.a > 1 SELECT * FROM t1 LEFT JOIN (t2, t3) ON t1.a=t2.a WHERE (t2.b=t3.b OR t2.b IS NULL) AND t1.a > 1
Those queries are considered to contain these nested joins:
t2 LEFT JOIN t3 ON t2.b=t3.b t2, t3
The nested join is formed in the first query with a left join operation, whereas in the second query it is formed with an inner join operation.
In the first query, the parentheses can be omitted: The
grammatical structure of the join expression will dictate the
same order of execution for join operations. For the second
query, the parentheses cannot be omitted, although the join
expression here can be interpreted unambiguously without them.
(In our extended syntax the parentheses in (t2,
t3) of the second query are required, although
theoretically the query could be parsed without them: We still
would have unambiguous syntactical structure for the query
because LEFT JOIN and ON
would play the role of the left and right delimiters for the
expression (t2,t3).)
The preceding examples demonstrate these points:
For join expressions involving only inner joins (and not outer joins), parentheses can be removed. You can remove parentheses and evaluate left to right (or, in fact, you can evaluate the tables in any order).
The same is not true, in general, for outer joins or for outer joins mixed with inner joins. Removal of parentheses may change the result.
Queries with nested outer joins are executed in the same
pipeline manner as queries with inner joins. More exactly, a
variation of the nested-loop join algorithm is exploited.
Recall by what algorithmic schema the nested-loop join
executes a query. Suppose that we have a join query over 3
tables T1,T2,T3 of the form:
SELECT * FROM T1 INNER JOIN T2 ON P1(T1,T2)
INNER JOIN T3 ON P2(T2,T3)
WHERE P(T1,T2,T3).
Here, P1(T1,T2) and
P2(T3,T3) are some join conditions (on
expressions), whereas P(t1,t2,t3) is a
condition over columns of tables T1,T2,T3.
The nested-loop join algorithm would execute this query in the following manner:
FOR each row t1 in T1 {
FOR each row t2 in T2 such that P1(t1,t2) {
FOR each row t3 in T3 such that P2(t2,t3) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
}
}
}
The notation t1||t2||t3 means “a row
constructed by concatenating the columns of rows
t1, t2, and
t3.” In some of the following
examples, NULL where a row name appears
means that NULL is used for each column of
that row. For example, t1||t2||NULL means
“a row constructed by concatenating the columns of rows
t1 and t2, and
NULL for each column of
t3.”
Now let's consider a query with nested outer joins:
SELECT * FROM T1 LEFT JOIN
(T2 LEFT JOIN T3 ON P2(T2,T3))
ON P1(T1,T2)
WHERE P(T1,T2,T3).
For this query, we modify the nested-loop pattern to get:
FOR each row t1 in T1 {
BOOL f1:=FALSE;
FOR each row t2 in T2 such that P1(t1,t2) {
BOOL f2:=FALSE;
FOR each row t3 in T3 such that P2(t2,t3) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
f2=TRUE;
f1=TRUE;
}
IF (!f2) {
IF P(t1,t2,NULL) {
t:=t1||t2||NULL; OUTPUT t;
}
f1=TRUE;
}
}
IF (!f1) {
IF P(t1,NULL,NULL) {
t:=t1||NULL||NULL; OUTPUT t;
}
}
}
In general, for any nested loop for the first inner table in
an outer join operation, a flag is introduced that is turned
off before the loop and is checked after the loop. The flag is
turned on when for the current row from the outer table a
match from the table representing the inner operand is found.
If at the end of the loop cycle the flag is still off, no
match has been found for the current row of the outer table.
In this case, the row is complemented by
NULL values for the columns of the inner
tables. The result row is passed to the final check for the
output or into the next nested loop, but only if the row
satisfies the join condition of all embedded outer joins.
In our example, the outer join table expressed by the following expression is embedded:
(T2 LEFT JOIN T3 ON P2(T2,T3))
Note that for the query with inner joins, the optimizer could choose a different order of nested loops, such as this one:
FOR each row t3 in T3 {
FOR each row t2 in T2 such that P2(t2,t3) {
FOR each row t1 in T1 such that P1(t1,t2) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
}
}
}
For the queries with outer joins, the optimizer can choose only such an order where loops for outer tables precede loops for inner tables. Thus, for our query with outer joins, only one nesting order is possible. For the following query, the optimizer will evaluate two different nestings:
SELECT * T1 LEFT JOIN (T2,T3) ON P1(T1,T2) AND P2(T1,T3) WHERE P(T1,T2,T3)
The nestings are these:
FOR each row t1 in T1 {
BOOL f1:=FALSE;
FOR each row t2 in T2 such that P1(t1,t2) {
FOR each row t3 in T3 such that P2(t1,t3) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
f1:=TRUE
}
}
IF (!f1) {
IF P(t1,NULL,NULL) {
t:=t1||NULL||NULL; OUTPUT t;
}
}
}
and:
FOR each row t1 in T1 {
BOOL f1:=FALSE;
FOR each row t3 in T3 such that P2(t1,t3) {
FOR each row t2 in T2 such that P1(t1,t2) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
f1:=TRUE
}
}
IF (!f1) {
IF P(t1,NULL,NULL) {
t:=t1||NULL||NULL; OUTPUT t;
}
}
}
In both nestings, T1 must be processed in
the outer loop because it is used in an outer join.
T2 and T3 are used in an
inner join, so that join must be processed in the inner loop.
However, because the join is an inner join,
T2 and T3 can be
processed in either order.
When discussing the nested-loop algorithm for inner joins, we
omitted some details whose impact on the performance of query
execution may be huge. We did not mention so-called
“pushed-down” conditions. Suppose that our
WHERE condition
P(T1,T2,T3) can be represented by a
conjunctive formula:
P(T1,T2,T2) = C1(T1) AND C2(T2) AND C3(T3).
In this case, MySQL actually uses the following nested-loop schema for the execution of the query with inner joins:
FOR each row t1 in T1 such that C1(t1) {
FOR each row t2 in T2 such that P1(t1,t2) AND C2(t2) {
FOR each row t3 in T3 such that P2(t2,t3) AND C3(t3) {
IF P(t1,t2,t3) {
t:=t1||t2||t3; OUTPUT t;
}
}
}
}
You see that each of the conjuncts C1(T1),
C2(T2), C3(T3) are
pushed out of the most inner loop to the most outer loop where
it can be evaluated. If C1(T1) is a very
restrictive condition, this condition pushdown may greatly
reduce the number of rows from table T1
passed to the inner loops. As a result, the execution time for
the query may improve immensely.
For a query with outer joins, the WHERE
condition is to be checked only after it has been found that
the current row from the outer table has a match in the inner
tables. Thus, the optimization of pushing conditions out of
the inner nested loops cannot be applied directly to queries
with outer joins. Here we have to introduce conditional
pushed-down predicates guarded by the flags that are turned on
when a match has been encountered.
For our example with outer joins with:
P(T1,T2,T3)=C1(T1) AND C(T2) AND C3(T3)
the nested-loop schema using guarded pushed-down conditions looks like this:
FOR each row t1 in T1 such that C1(t1) {
BOOL f1:=FALSE;
FOR each row t2 in T2
such that P1(t1,t2) AND (f1?C2(t2):TRUE) {
BOOL f2:=FALSE;
FOR each row t3 in T3
such that P2(t2,t3) AND (f1&&f2?C3(t3):TRUE) {
IF (f1&&f2?TRUE:(C2(t2) AND C3(t3))) {
t:=t1||t2||t3; OUTPUT t;
}
f2=TRUE;
f1=TRUE;
}
IF (!f2) {
IF (f1?TRUE:C2(t2) && P(t1,t2,NULL)) {
t:=t1||t2||NULL; OUTPUT t;
}
f1=TRUE;
}
}
IF (!f1 && P(t1,NULL,NULL)) {
t:=t1||NULL||NULL; OUTPUT t;
}
}
In general, pushed-down predicates can be extracted from join
conditions such as P1(T1,T2) and
P(T2,T3). In this case, a pushed-down
predicate is guarded also by a flag that prevents checking the
predicate for the NULL-complemented row
generated by the corresponding outer join operation.
Note that access by key from one inner table to another in the
same nested join is prohibited if it is induced by a predicate
from the WHERE condition. (We could use
conditional key access in this case, but this technique is not
employed yet in MySQL 5.1.)
Table expressions in the FROM clause of a
query are simplified in many cases.
At the parser stage, queries with right outer joins operations are converted to equivalent queries containing only left join operations. In the general case, the conversion is performed according to the following rule:
(T1, ...) RIGHT JOIN (T2,...) ON P(T1,...,T2,...) = (T2, ...) LEFT JOIN (T1,...) ON P(T1,...,T2,...)
All inner join expressions of the form T1 INNER JOIN
T2 ON P(T1,T2) are replaced by the list
T1,T2, P(T1,T2) being
joined as a conjunct to the WHERE condition
(or to the join condition of the embedding join, if there is
any).
When the optimizer evaluates plans for join queries with outer join operation, it takes into consideration only the plans where, for each such operation, the outer tables are accessed before the inner tables. The optimizer options are limited because only such plans enables us to execute queries with outer joins operations by the nested loop schema.
Suppose that we have a query of the form:
SELECT * T1 LEFT JOIN T2 ON P1(T1,T2) WHERE P(T1,T2) AND R(T2)
with R(T2) narrowing greatly the number of
matching rows from table T2. If we executed
the query as it is, the optimizer would have no other choice
besides to access table T1 before table
T2 that may lead to a very inefficient
execution plan.
Fortunately, MySQL converts such a query into a query without
an outer join operation if the WHERE
condition is null-rejected. A condition is called
null-rejected for an outer join operation if it evaluates to
FALSE or to UNKNOWN for
any NULL-complemented row built for the
operation.
Thus, for this outer join:
T1 LEFT JOIN T2 ON T1.A=T2.A
Conditions such as these are null-rejected:
T2.B IS NOT NULL, T2.B > 3, T2.C <= T1.C, T2.B < 2 OR T2.C > 1
Conditions such as these are not null-rejected:
T2.B IS NULL, T1.B < 3 OR T2.B IS NOT NULL, T1.B < 3 OR T2.B > 3
The general rules for checking whether a condition is null-rejected for an outer join operation are simple. A condition is null-rejected in the following cases:
If it is of the form A IS NOT NULL,
where A is an attribute of any of the
inner tables
If it is a predicate containing a reference to an inner
table that evaluates to UNKNOWN when
one of its arguments is NULL
If it is a conjunction containing a null-rejected condition as a conjunct
If it is a disjunction of null-rejected conditions
A condition can be null-rejected for one outer join operation in a query and not null-rejected for another. In the query:
SELECT * FROM T1 LEFT JOIN T2 ON T2.A=T1.A
LEFT JOIN T3 ON T3.B=T1.B
WHERE T3.C > 0
the WHERE condition is null-rejected for
the second outer join operation but is not null-rejected for
the first one.
If the WHERE condition is null-rejected for
an outer join operation in a query, the outer join operation
is replaced by an inner join operation.
For example, the preceding query is replaced with the query:
SELECT * FROM T1 LEFT JOIN T2 ON T2.A=T1.A
INNER JOIN T3 ON T3.B=T1.B
WHERE T3.C > 0
For the original query, the optimizer would evaluate plans
compatible with only one access order
T1,T2,T3. For the replacing query, it
additionally considers the access sequence
T3,T1,T2.
A conversion of one outer join operation may trigger a conversion of another. Thus, the query:
SELECT * FROM T1 LEFT JOIN T2 ON T2.A=T1.A
LEFT JOIN T3 ON T3.B=T2.B
WHERE T3.C > 0
will be first converted to the query:
SELECT * FROM T1 LEFT JOIN T2 ON T2.A=T1.A
INNER JOIN T3 ON T3.B=T2.B
WHERE T3.C > 0
which is equivalent to the query:
SELECT * FROM (T1 LEFT JOIN T2 ON T2.A=T1.A), T3 WHERE T3.C > 0 AND T3.B=T2.B
Now the remaining outer join operation can be replaced by an
inner join, too, because the condition
T3.B=T2.B is null-rejected and we get a
query without outer joins at all:
SELECT * FROM (T1 INNER JOIN T2 ON T2.A=T1.A), T3 WHERE T3.C > 0 AND T3.B=T2.B
Sometimes we succeed in replacing an embedded outer join operation, but cannot convert the embedding outer join. The following query:
SELECT * FROM T1 LEFT JOIN
(T2 LEFT JOIN T3 ON T3.B=T2.B)
ON T2.A=T1.A
WHERE T3.C > 0
is converted to:
SELECT * FROM T1 LEFT JOIN
(T2 INNER JOIN T3 ON T3.B=T2.B)
ON T2.A=T1.A
WHERE T3.C > 0,
That can be rewritten only to the form still containing the embedding outer join operation:
SELECT * FROM T1 LEFT JOIN
(T2,T3)
ON (T2.A=T1.A AND T3.B=T2.B)
WHERE T3.C > 0.
When trying to convert an embedded outer join operation in a
query, we must take into account the join condition for the
embedding outer join together with the
WHERE condition. In the query:
SELECT * FROM T1 LEFT JOIN
(T2 LEFT JOIN T3 ON T3.B=T2.B)
ON T2.A=T1.A AND T3.C=T1.C
WHERE T3.D > 0 OR T1.D > 0
the WHERE condition is not null-rejected
for the embedded outer join, but the join condition of the
embedding outer join T2.A=T1.A AND
T3.C=T1.C is null-rejected. So the query can be
converted to:
SELECT * FROM T1 LEFT JOIN
(T2, T3)
ON T2.A=T1.A AND T3.C=T1.C AND T3.B=T2.B
WHERE T3.D > 0 OR T1.D > 0
In some cases, MySQL can use an index to satisfy an
ORDER BY clause without doing any extra
sorting.
The index can also be used even if the ORDER
BY does not match the index exactly, as long as all
of the unused portions of the index and all the extra
ORDER BY columns are constants in the
WHERE clause. The following queries use the
index to resolve the ORDER BY part:
SELECT * FROM t1 ORDER BYkey_part1,key_part2,... ; SELECT * FROM t1 WHEREkey_part1=constantORDER BYkey_part2; SELECT * FROM t1 ORDER BYkey_part1DESC,key_part2DESC; SELECT * FROM t1 WHEREkey_part1=1 ORDER BYkey_part1DESC,key_part2DESC;
In some cases, MySQL cannot use indexes
to resolve the ORDER BY, although it still
uses indexes to find the rows that match the
WHERE clause. These cases include the
following:
You use ORDER BY on different keys:
SELECT * FROM t1 ORDER BYkey1,key2;
You use ORDER BY on nonconsecutive
parts of a key:
SELECT * FROM t1 WHEREkey2=constantORDER BYkey_part2;
You mix ASC and
DESC:
SELECT * FROM t1 ORDER BYkey_part1DESC,key_part2ASC;
The key used to fetch the rows is not the same as the one
used in the ORDER BY:
SELECT * FROM t1 WHEREkey2=constantORDER BYkey1;
You use ORDER BY with an expression
that includes terms other than the key column name:
SELECT * FROM t1 ORDER BY ABS(key); SELECT * FROM t1 ORDER BY -key;
You are joining many tables, and the columns in the
ORDER BY are not all from the first
nonconstant table that is used to retrieve rows. (This is
the first table in the
EXPLAIN output that does
not have a const join
type.)
You have different ORDER BY and
GROUP BY expressions.
You index only a prefix of a column named in the
ORDER BY clause. In this case, the
index cannot be used to fully resolve the sort order. For
example, if you have a
CHAR(20) column, but index
only the first 10 bytes, the index cannot distinguish
values past the 10th byte and a
filesort will be needed.
The type of table index used does not store rows in order.
For example, this is true for a HASH
index in a MEMORY table.
Availability of an index for sorting may be affected by the
use of column aliases. Suppose that the column
t1.a is indexed. In this statement, the
name of the column in the select list is a.
It refers to t1.a, so for the reference to
a in the ORDER BY, the
index can be used:
SELECT a FROM t1 ORDER BY a;
In this statement, the name of the column in the select list
is also a, but it is the alias name. It
refers to ABS(a), so for the reference to
a in the ORDER BY, the
index cannot be used:
SELECT ABS(a) AS a FROM t1 ORDER BY a;
In the following statement, the ORDER BY
refers to a name that is not the name of a column in the
select list. But there is a column in t1
named a, so the ORDER BY
uses that, and the index can be used. (The resulting sort
order may be completely different from the order for
ABS(a), of course.)
SELECT ABS(a) AS b FROM t1 ORDER BY a;
By default, MySQL sorts all GROUP BY
queries as if
you specified col1,
col2, ...ORDER BY
in the query as
well. If you include an col1,
col2, ...ORDER BY clause
explicitly that contains the same column list, MySQL optimizes
it away without any speed penalty, although the sorting still
occurs. If a query includes GROUP BY but
you want to avoid the overhead of sorting the result, you can
suppress sorting by specifying ORDER BY
NULL. For example:
INSERT INTO foo SELECT a, COUNT(*) FROM bar GROUP BY a ORDER BY NULL;
With EXPLAIN SELECT ... ORDER BY, you can
check whether MySQL can use indexes to resolve the query. It
cannot if you see Using filesort in the
Extra column. See
Section 7.2.1, “Optimizing Queries with EXPLAIN”.
MySQL has two filesort algorithms for
sorting and retrieving results. The original method uses only
the ORDER BY columns. The modified method
uses not just the ORDER BY columns, but all
the columns used in the query.
The optimizer selects which filesort
algorithm to use. It normally uses the modified algorithm
except when BLOB or
TEXT columns are involved, in
which case it uses the original algorithm.
The original filesort algorithm works as
follows:
Read all rows according to key or by table scanning. Rows
that do not match the WHERE clause are
skipped.
For each row, store a pair of values in a buffer (the sort
key and the row pointer). The size of the buffer is the
value of the
sort_buffer_size system
variable.
When the buffer gets full, run a qsort (quicksort) on it and store the result in a temporary file. Save a pointer to the sorted block. (If all pairs fit into the sort buffer, no temporary file is created.)
Repeat the preceding steps until all rows have been read.
Do a multi-merge of up to MERGEBUFF (7)
regions to one block in another temporary file. Repeat
until all blocks from the first file are in the second
file.
Repeat the following until there are fewer than
MERGEBUFF2 (15) blocks left.
On the last multi-merge, only the pointer to the row (the last part of the sort key) is written to a result file.
Read the rows in sorted order by using the row pointers in
the result file. To optimize this, we read in a big block
of row pointers, sort them, and use them to read the rows
in sorted order into a row buffer. The size of the buffer
is the value of the
read_rnd_buffer_size
system variable. The code for this step is in the
sql/records.cc source file.
One problem with this approach is that it reads rows twice:
One time when evaluating the WHERE clause,
and again after sorting the pair values. And even if the rows
were accessed successively the first time (for example, if a
table scan is done), the second time they are accessed
randomly. (The sort keys are ordered, but the row positions
are not.)
The modified filesort algorithm
incorporates an optimization such that it records not only the
sort key value and row position, but also the columns required
for the query. This avoids reading the rows twice. The
modified filesort algorithm works like
this:
Read the rows that match the WHERE
clause.
For each row, record a tuple of values consisting of the sort key value and row position, and also the columns required for the query.
Sort the tuples by sort key value
Retrieve the rows in sorted order, but read the required columns directly from the sorted tuples rather than by accessing the table a second time.
Using the modified filesort algorithm, the
tuples are longer than the pairs used in the original method,
and fewer of them fit in the sort buffer (the size of which is
given by sort_buffer_size).
As a result, it is possible for the extra I/O to make the
modified approach slower, not faster. To avoid a slowdown, the
optimization is used only if the total size of the extra
columns in the sort tuple does not exceed the value of the
max_length_for_sort_data
system variable. (A symptom of setting the value of this
variable too high is that you should see high disk activity
and low CPU activity.)
For slow queries for which filesort is not
used, you might try lowering
max_length_for_sort_data to a
value that is appropriate to trigger a
filesort.
If you want to increase ORDER BY speed,
check whether you can get MySQL to use indexes rather than an
extra sorting phase. If this is not possible, you can try the
following strategies:
Increase the size of the
sort_buffer_size
variable.
Increase the size of the
read_rnd_buffer_size
variable.
Use less RAM per row by declaring columns only as large as
they need to be to hold the values stored in them. For
example, CHAR(16) is better than
CHAR(200) if values never exceed 16
characters.
Change tmpdir to point to
a dedicated file system with large amounts of free space.
Also, this option accepts several paths that are used in
round-robin fashion, so you can use this feature to spread
the load across several directories. Paths should be
separated by colon characters
(“:”) on Unix and
semicolon characters (“;”)
on Windows, NetWare, and OS/2. The paths should be for
directories in file systems that are located on different
physical disks, not different
partitions on the same disk.
The most general way to satisfy a GROUP BY
clause is to scan the whole table and create a new temporary
table where all rows from each group are consecutive, and then
use this temporary table to discover groups and apply
aggregate functions (if any). In some cases, MySQL is able to
do much better than that and to avoid creation of temporary
tables by using index access.
The most important preconditions for using indexes for
GROUP BY are that all GROUP
BY columns reference attributes from the same index,
and that the index stores its keys in order (for example, this
is a BTREE index and not a
HASH index). Whether use of temporary
tables can be replaced by index access also depends on which
parts of an index are used in a query, the conditions
specified for these parts, and the selected aggregate
functions.
There are two ways to execute a GROUP BY
query through index access, as detailed in the following
sections. In the first method, the grouping operation is
applied together with all range predicates (if any). The
second method first performs a range scan, and then groups the
resulting tuples.
In MySQL, GROUP BY is used for sorting, so
the server may also apply ORDER BY
optimizations to grouping. See
Section 7.3.1.11, “ORDER BY Optimization”.
The most efficient way to process GROUP
BY is when an index is used to directly retrieve
the grouping columns. With this access method, MySQL uses
the property of some index types that the keys are ordered
(for example, BTREE). This property
enables use of lookup groups in an index without having to
consider all keys in the index that satisfy all
WHERE conditions. This access method
considers only a fraction of the keys in an index, so it is
called a loose index scan. When there
is no WHERE clause, a loose index scan
reads as many keys as the number of groups, which may be a
much smaller number than that of all keys. If the
WHERE clause contains range predicates
(see the discussion of the
range join type in
Section 7.2.1, “Optimizing Queries with EXPLAIN”), a loose index scan looks
up the first key of each group that satisfies the range
conditions, and again reads the least possible number of
keys. This is possible under the following conditions:
The query is over a single table.
The GROUP BY names only columns that
form a leftmost prefix of the index and no other
columns. (If, instead of GROUP BY,
the query has a DISTINCT clause, all
distinct attributes refer to columns that form a
leftmost prefix of the index.) For example, if a table
t1 has an index on
(c1,c2,c3), loose index scan is
applicable if the query has GROUP BY c1,
c2,. It is not applicable if the query has
GROUP BY c2, c3 (the columns are not
a leftmost prefix) or GROUP BY c1, c2,
c4 (c4 is not in the
index).
The only aggregate functions used in the select list (if
any) are MIN() and
MAX(), and all of them
refer to the same column. The column must be in the
index and must follow the columns in the GROUP
BY.
Any other parts of the index than those from the
GROUP BY referenced in the query must
be constants (that is, they must be referenced in
equalities with constants), except for the argument of
MIN() or
MAX() functions.
For columns in the index, full column values must be
indexed, not just a prefix. For example, with
c1 VARCHAR(20), INDEX (c1(10)), the
index cannot be used for loose index scan.
If loose index scan is applicable to a query, the
EXPLAIN output shows
Using index for group-by in the
Extra column.
Assume that there is an index
idx(c1,c2,c3) on table
t1(c1,c2,c3,c4). The loose index scan
access method can be used for the following queries:
SELECT c1, c2 FROM t1 GROUP BY c1, c2; SELECT DISTINCT c1, c2 FROM t1; SELECT c1, MIN(c2) FROM t1 GROUP BY c1; SELECT c1, c2 FROM t1 WHERE c1 <constGROUP BY c1, c2; SELECT MAX(c3), MIN(c3), c1, c2 FROM t1 WHERE c2 >constGROUP BY c1, c2; SELECT c2 FROM t1 WHERE c1 <constGROUP BY c1, c2; SELECT c1, c2 FROM t1 WHERE c3 =constGROUP BY c1, c2;
The following queries cannot be executed with this quick select method, for the reasons given:
There are aggregate functions other than
MIN() or
MAX():
SELECT c1, SUM(c2) FROM t1 GROUP BY c1;
The columns in the GROUP BY clause do
not form a leftmost prefix of the index:
SELECT c1, c2 FROM t1 GROUP BY c2, c3;
The query refers to a part of a key that comes after the
GROUP BY part, and for which there is
no equality with a constant:
SELECT c1, c3 FROM t1 GROUP BY c1, c2;
Were the query to include WHERE c3 =
, loose index
scan could be used.
const
A tight index scan may be either a full index scan or a range index scan, depending on the query conditions.
When the conditions for a loose index scan are not met, it
still may be possible to avoid creation of temporary tables
for GROUP BY queries. If there are range
conditions in the WHERE clause, this
method reads only the keys that satisfy these conditions.
Otherwise, it performs an index scan. Because this method
reads all keys in each range defined by the
WHERE clause, or scans the whole index if
there are no range conditions, we term it a tight
index scan. With a tight index scan, the
grouping operation is performed only after all keys that
satisfy the range conditions have been found.
For this method to work, it is sufficient that there is a
constant equality condition for all columns in a query
referring to parts of the key coming before or in between
parts of the GROUP BY key. The constants
from the equality conditions fill in any “gaps”
in the search keys so that it is possible to form complete
prefixes of the index. These index prefixes then can be used
for index lookups. If we require sorting of the
GROUP BY result, and it is possible to
form search keys that are prefixes of the index, MySQL also
avoids extra sorting operations because searching with
prefixes in an ordered index already retrieves all the keys
in order.
Assume that there is an index
idx(c1,c2,c3) on table
t1(c1,c2,c3,c4). The following queries do
not work with the loose index scan access method described
earlier, but still work with the tight index scan access
method.
There is a gap in the GROUP BY, but
it is covered by the condition c2 =
'a':
SELECT c1, c2, c3 FROM t1 WHERE c2 = 'a' GROUP BY c1, c3;
The GROUP BY does not begin with the
first part of the key, but there is a condition that
provides a constant for that part:
SELECT c1, c2, c3 FROM t1 WHERE c1 = 'a' GROUP BY c2, c3;
DISTINCT combined with ORDER
BY needs a temporary table in many cases.
Because DISTINCT may use GROUP
BY, you should be aware of how MySQL works with
columns in ORDER BY or
HAVING clauses that are not part of the
selected columns. See
Section 11.16.3, “GROUP BY and HAVING with Hidden
Columns”.
In most cases, a DISTINCT clause can be
considered as a special case of GROUP BY.
For example, the following two queries are equivalent:
SELECT DISTINCT c1, c2, c3 FROM t1 WHERE c1 >const; SELECT c1, c2, c3 FROM t1 WHERE c1 >constGROUP BY c1, c2, c3;
Due to this equivalence, the optimizations applicable to
GROUP BY queries can be also applied to
queries with a DISTINCT clause. Thus, for
more details on the optimization possibilities for
DISTINCT queries, see
Section 7.3.1.12, “GROUP BY Optimization”.
When combining LIMIT
with
row_countDISTINCT, MySQL stops as soon as it finds
row_count unique rows.
If you do not use columns from all tables named in a query,
MySQL stops scanning any unused tables as soon as it finds the
first match. In the following case, assuming that
t1 is used before t2
(which you can check with
EXPLAIN), MySQL stops reading
from t2 (for any particular row in
t1) when it finds the first row in
t2:
SELECT DISTINCT t1.a FROM t1, t2 where t1.a=t2.a;
Certain optimizations are applicable to comparisons that use
the IN operator to test subquery results
(or that use =ANY, which is equivalent).
This section discusses these optimizations, particularly with
regard to the challenges that NULL values
present. Suggestions on what you can do to help the optimizer
are given at the end of the discussion.
Consider the following subquery comparison:
outer_exprIN (SELECTinner_exprFROM ... WHEREsubquery_where)
MySQL evaluates queries “from outside to inside.”
That is, it first obtains the value of the outer expression
outer_expr, and then runs the
subquery and captures the rows that it produces.
A very useful optimization is to “inform” the
subquery that the only rows of interest are those where the
inner expression inner_expr is
equal to outer_expr. This is done
by pushing down an appropriate equality into the subquery's
WHERE clause. That is, the comparison is
converted to this:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereANDouter_expr=inner_expr)
After the conversion, MySQL can use the pushed-down equality to limit the number of rows that it must examine when evaluating the subquery.
More generally, a comparison of N
values to a subquery that returns
N-value rows is subject to the same
conversion. If oe_i and
ie_i represent corresponding outer
and inner expression values, this subquery comparison:
(oe_1, ...,oe_N) IN (SELECTie_1, ...,ie_NFROM ... WHEREsubquery_where)
Becomes:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereANDoe_1=ie_1AND ... ANDoe_N=ie_N)
The following discussion assumes a single pair of outer and inner expression values for simplicity.
The conversion just described has its limitations. It is valid
only if we ignore possible NULL values.
That is, the “pushdown” strategy works as long as
both of these two conditions are true:
When either or both of those conditions do not hold, optimization is more complex.
Suppose that outer_expr is known to
be a non-NULL value but the subquery does
not produce a row such that
outer_expr =
inner_expr. Then
evaluates as follows:
outer_expr IN (SELECT
...)
In this situation, the approach of looking for rows with
is no longer
valid. It is necessary to look for such rows, but if none are
found, also look for rows where
outer_expr =
inner_exprinner_expr is
NULL. Roughly speaking, the subquery can be
converted to:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereAND (outer_expr=inner_exprORinner_exprIS NULL))
The need to evaluate the extra IS
NULL condition is why MySQL has the
ref_or_null access method:
mysql>EXPLAIN->SELECT->outer_exprIN (SELECT t2.maybe_null_keyFROM t2, t3 WHERE ...)-> FROM t1; *************************** 1. row *************************** id: 1 select_type: PRIMARY table: t1 ... *************************** 2. row *************************** id: 2 select_type: DEPENDENT SUBQUERY table: t2 type: ref_or_null possible_keys: maybe_null_key key: maybe_null_key key_len: 5 ref: func rows: 2 Extra: Using where; Using index ...
The unique_subquery and
index_subquery
subquery-specific access methods also have or-null variants.
However, they are not visible in
EXPLAIN output, so you must use
EXPLAIN
EXTENDED followed by SHOW
WARNINGS (note the checking NULL
in the warning message):
mysql>EXPLAIN EXTENDED->SELECT*************************** 1. row *************************** id: 1 select_type: PRIMARY table: t1 ... *************************** 2. row *************************** id: 2 select_type: DEPENDENT SUBQUERY table: t2 type: index_subquery possible_keys: maybe_null_key key: maybe_null_key key_len: 5 ref: func rows: 2 Extra: Using index mysql>outer_exprIN (SELECT maybe_null_key FROM t2) FROM t1\GSHOW WARNINGS\G*************************** 1. row *************************** Level: Note Code: 1003 Message: select (`test`.`t1`.`outer_expr`, (((`test`.`t1`.`outer_expr`) in t2 on maybe_null_key checking NULL))) AS `outer_expr IN (SELECT maybe_null_key FROM t2)` from `test`.`t1`
The additional OR ... IS NULL condition
makes query execution slightly more complicated (and some
optimizations within the subquery become inapplicable), but
generally this is tolerable.
The situation is much worse when
outer_expr can be
NULL. According to the SQL interpretation
of NULL as “unknown value,”
NULL IN (SELECT should evaluate to:
inner_expr
...)
For proper evaluation, it is necessary to be able to check
whether the SELECT has produced
any rows at all, so
cannot be
pushed down into the subquery. This is a problem, because many
real world subqueries become very slow unless the equality can
be pushed down.
outer_expr =
inner_expr
Essentially, there must be different ways to execute the
subquery depending on the value of
outer_expr. In MySQL
5.1 before 5.1.16, the optimizer chose speed over
distinguishing a NULL from
FALSE result, so for some queries, you
might get a FALSE result rather than
NULL.
As of MySQL 5.1.16, the optimizer chooses SQL compliance over
speed, so it accounts for the possibility that
outer_expr might be
NULL.
If outer_expr is
NULL, to evaluate the following expression,
it is necessary to run the
SELECT to determine whether it
produces any rows:
NULL IN (SELECTinner_exprFROM ... WHEREsubquery_where)
It is necessary to run the original
SELECT here, without any
pushed-down equalities of the kind mentioned earlier.
On the other hand, when outer_expr
is not NULL, it is absolutely essential
that this comparison:
outer_exprIN (SELECTinner_exprFROM ... WHEREsubquery_where)
be converted to this expression that uses a pushed-down condition:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereANDouter_expr=inner_expr)
Without this conversion, subqueries will be slow. To solve the dilemma of whether to push down or not push down conditions into the subquery, the conditions are wrapped in “trigger” functions. Thus, an expression of the following form:
outer_exprIN (SELECTinner_exprFROM ... WHEREsubquery_where)
is converted into:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereAND trigcond(outer_expr=inner_expr))
More generally, if the subquery comparison is based on several pairs of outer and inner expressions, the conversion takes this comparison:
(oe_1, ...,oe_N) IN (SELECTie_1, ...,ie_NFROM ... WHEREsubquery_where)
and converts it to this expression:
EXISTS (SELECT 1 FROM ... WHEREsubquery_whereAND trigcond(oe_1=ie_1) AND ... AND trigcond(oe_N=ie_N) )
Each trigcond(
is a special function that evaluates to the following values:
X)
X when the
“linked” outer expression
oe_i is not
NULL
TRUE when the “linked”
outer expression oe_i is
NULL
Note that trigger functions are not
triggers of the kind that you create with
CREATE TRIGGER.
Equalities that are wrapped into trigcond()
functions are not first class predicates for the query
optimizer. Most optimizations cannot deal with predicates that
may be turned on and off at query execution time, so they
assume any
trigcond( to
be an unknown function and ignore it. At the moment, triggered
equalities can be used by those optimizations:
X)
Reference optimizations:
trigcond( can
be used to construct
X=Y
[OR Y IS NULL])ref,
eq_ref, or
ref_or_null table
accesses.
Index lookup-based subquery execution engines:
trigcond(
can be used to construct
X=Y)unique_subquery or
index_subquery
accesses.
Table-condition generator: If the subquery is a join of several tables, the triggered condition will be checked as soon as possible.
When the optimizer uses a triggered condition to create some
kind of index lookup-based access (as for the first two items
of the preceding list), it must have a fallback strategy for
the case when the condition is turned off. This fallback
strategy is always the same: Do a full table scan. In
EXPLAIN output, the fallback
shows up as Full scan on NULL key in the
Extra column:
mysql>EXPLAIN SELECT t1.col1,->t1.col1 IN (SELECT t2.key1 FROM t2 WHERE t2.col2=t1.col2) FROM t1\G*************************** 1. row *************************** id: 1 select_type: PRIMARY table: t1 ... *************************** 2. row *************************** id: 2 select_type: DEPENDENT SUBQUERY table: t2 type: index_subquery possible_keys: key1 key: key1 key_len: 5 ref: func rows: 2 Extra: Using where; Full scan on NULL key
If you run EXPLAIN
EXTENDED followed by SHOW
WARNINGS, you can see the triggered condition:
*************************** 1. row ***************************
Level: Note
Code: 1003
Message: select `test`.`t1`.`col1` AS `col1`,
<in_optimizer>(`test`.`t1`.`col1`,
<exists>(<index_lookup>(<cache>(`test`.`t1`.`col1`) in t2
on key1 checking NULL
where (`test`.`t2`.`col2` = `test`.`t1`.`col2`) having
trigcond(<is_not_null_test>(`test`.`t2`.`key1`))))) AS
`t1.col1 IN (select t2.key1 from t2 where t2.col2=t1.col2)`
from `test`.`t1`
The use of triggered conditions has some performance
implications. A NULL IN (SELECT ...)
expression now may cause a full table scan (which is slow)
when it previously did not. This is the price paid for correct
results (the goal of the trigger-condition strategy was to
improve compliance and not speed).
For multiple-table subqueries, execution of NULL IN
(SELECT ...) will be particularly slow because the
join optimizer doesn't optimize for the case where the outer
expression is NULL. It assumes that
subquery evaluations with NULL on the left
side are very rare, even if there are statistics that indicate
otherwise. On the other hand, if the outer expression might be
NULL but never actually is, there is no
performance penalty.
To help the query optimizer better execute your queries, use these tips:
A column must be declared as NOT NULL
if it really is. (This also helps other aspects of the
optimizer.)
If you don't need to distinguish a NULL
from FALSE subquery result, you can
easily avoid the slow execution path. Replace a comparison
that looks like this:
outer_exprIN (SELECTinner_exprFROM ...)
with this expression:
(outer_exprIS NOT NULL) AND (outer_exprIN (SELECTinner_exprFROM ...))
Then NULL IN (SELECT ...) will never be
evaluated because MySQL stops evaluating
AND parts as soon as the
expression result is clear.
In some cases, MySQL handles a query differently when you are
using LIMIT
and not using
row_countHAVING:
If you are selecting only a few rows with
LIMIT, MySQL uses indexes in some cases
when normally it would prefer to do a full table scan.
If you use LIMIT
with
row_countORDER BY, MySQL ends the sorting as
soon as it has found the first
row_count rows of the sorted
result, rather than sorting the entire result. If ordering
is done by using an index, this is very fast. If a
filesort must be done, all rows that match the query
without the LIMIT clause must be
selected, and most or all of them must be sorted, before
it can be ascertained that the first
row_count rows have been found.
In either case, after the initial rows have been found,
there is no need to sort any remainder of the result set,
and MySQL does not do so.
When combining LIMIT
with
row_countDISTINCT, MySQL stops as soon as it
finds row_count unique rows.
In some cases, a GROUP BY can be
resolved by reading the key in order (or doing a sort on
the key) and then calculating summaries until the key
value changes. In this case, LIMIT
does not
calculate any unnecessary row_countGROUP BY
values.
As soon as MySQL has sent the required number of rows to
the client, it aborts the query unless you are using
SQL_CALC_FOUND_ROWS.
LIMIT 0 quickly returns an empty set.
This can be useful for checking the validity of a query.
When using one of the MySQL APIs, it can also be employed
for obtaining the types of the result columns. (This trick
does not work in the MySQL Monitor (the
mysql program), which merely displays
Empty set in such cases; you should
instead use SHOW COLUMNS or
DESCRIBE for this purpose.)
When the server uses temporary tables to resolve the
query, it uses the LIMIT
clause to
calculate how much space is required.
row_count
The output from EXPLAIN shows
ALL in the
type column when MySQL uses a table scan to
resolve a query. This usually happens under the following
conditions:
The table is so small that it is faster to perform a table scan than to bother with a key lookup. This is common for tables with fewer than 10 rows and a short row length.
There are no usable restrictions in the
ON or WHERE clause
for indexed columns.
You are comparing indexed columns with constant values and
MySQL has calculated (based on the index tree) that the
constants cover too large a part of the table and that a
table scan would be faster. See
Section 7.3.1.2, “WHERE Clause Optimization”.
You are using a key with low cardinality (many rows match the key value) through another column. In this case, MySQL assumes that by using the key it probably will do many key lookups and that a table scan would be faster.
For small tables, a table scan often is appropriate and the performance impact is negligible. For large tables, try the following techniques to avoid having the optimizer incorrectly choose a table scan:
Use ANALYZE TABLE
to update
the key distributions for the scanned table. See
Section 12.4.2.1, “tbl_nameANALYZE TABLE Syntax”.
Use FORCE INDEX for the scanned table
to tell MySQL that table scans are very expensive compared
to using the given index:
SELECT * FROM t1, t2 FORCE INDEX (index_for_column) WHERE t1.col_name=t2.col_name;
Start mysqld with the
--max-seeks-for-key=1000
option or use SET
max_seeks_for_key=1000 to tell the optimizer to
assume that no key scan causes more than 1,000 key seeks.
See Section 5.1.4, “Server System Variables”.
The time required for inserting a row is determined by the following factors, where the numbers indicate approximate proportions:
Connecting: (3)
Sending query to server: (2)
Parsing query: (2)
Inserting row: (1 × size of row)
Inserting indexes: (1 × number of indexes)
Closing: (1)
This does not take into consideration the initial overhead to open tables, which is done once for each concurrently running query.
The size of the table slows down the insertion of indexes by
log N, assuming B-tree indexes.
You can use the following methods to speed up inserts:
If you are inserting many rows from the same client at the
same time, use INSERT
statements with multiple VALUES lists
to insert several rows at a time. This is considerably
faster (many times faster in some cases) than using
separate single-row INSERT
statements. If you are adding data to a nonempty table,
you can tune the
bulk_insert_buffer_size
variable to make data insertion even faster. See
Section 5.1.4, “Server System Variables”.
If multiple clients are inserting a lot of rows, you can
get higher speed by using the INSERT
DELAYED statement. See
Section 12.2.5.2, “INSERT DELAYED Syntax”.
For a MyISAM table, you can use
concurrent inserts to add rows at the same time that
SELECT statements are
running, if there are no deleted rows in middle of the
data file. See Section 7.7.3, “Concurrent Inserts”.
When loading a table from a text file, use
LOAD DATA
INFILE. This is usually 20 times faster than
using INSERT statements.
See Section 12.2.6, “LOAD DATA INFILE
Syntax”.
With some extra work, it is possible to make
LOAD DATA
INFILE run even faster for a
MyISAM table when the table has many
indexes. Use the following procedure:
Optionally create the table with
CREATE TABLE.
Execute a FLUSH
TABLES statement or a mysqladmin
flush-tables command.
Use myisamchk --keys-used=0 -rq
/path/to/db/tbl_name.
This removes all use of indexes for the table.
Insert data into the table with
LOAD DATA
INFILE. This does not update any indexes and
therefore is very fast.
If you intend only to read from the table in the future, use myisampack to compress it. See Section 13.5.3.3, “Compressed Table Characteristics”.
Re-create the indexes with myisamchk -rq
/path/to/db/tbl_name.
This creates the index tree in memory before writing
it to disk, which is much faster that updating the
index during
LOAD DATA
INFILE because it avoids lots of disk seeks.
The resulting index tree is also perfectly balanced.
Execute a FLUSH
TABLES statement or a mysqladmin
flush-tables command.
LOAD DATA
INFILE performs the preceding optimization
automatically if the MyISAM table into
which you insert data is empty. The main difference
between automatic optimization and using the procedure
explicitly is that you can let
myisamchk allocate much more temporary
memory for the index creation than you might want the
server to allocate for index re-creation when it executes
the LOAD DATA
INFILE statement.
You can also disable or enable the nonunique indexes for a
MyISAM table by using the following
statements rather than myisamchk. If
you use these statements, you can skip the
FLUSH
TABLE operations:
ALTER TABLEtbl_nameDISABLE KEYS; ALTER TABLEtbl_nameENABLE KEYS;
To speed up INSERT
operations that are performed with multiple statements for
nontransactional tables, lock your tables:
LOCK TABLES a WRITE; INSERT INTO a VALUES (1,23),(2,34),(4,33); INSERT INTO a VALUES (8,26),(6,29); ... UNLOCK TABLES;
This benefits performance because the index buffer is
flushed to disk only once, after all
INSERT statements have
completed. Normally, there would be as many index buffer
flushes as there are INSERT
statements. Explicit locking statements are not needed if
you can insert all rows with a single
INSERT.
To obtain faster insertions for transactional tables, you
should use START
TRANSACTION and
COMMIT instead of
LOCK TABLES.
Locking also lowers the total time for multiple-connection tests, although the maximum wait time for individual connections might go up because they wait for locks. Suppose that five clients attempt to perform inserts simultaneously as follows:
Connection 1 does 1000 inserts
Connections 2, 3, and 4 do 1 insert
Connection 5 does 1000 inserts
If you do not use locking, connections 2, 3, and 4 finish before 1 and 5. If you use locking, connections 2, 3, and 4 probably do not finish before 1 or 5, but the total time should be about 40% faster.
INSERT,
UPDATE, and
DELETE operations are very
fast in MySQL, but you can obtain better overall
performance by adding locks around everything that does
more than about five successive inserts or updates. If you
do very many successive inserts, you could do a
LOCK TABLES followed by an
UNLOCK
TABLES once in a while (each 1,000 rows or so)
to permit other threads to access table. This would still
result in a nice performance gain.
INSERT is still much slower
for loading data than
LOAD DATA
INFILE, even when using the strategies just
outlined.
To increase performance for MyISAM
tables, for both
LOAD DATA
INFILE and
INSERT, enlarge the key
cache by increasing the
key_buffer_size system
variable. See Section 7.9.2, “Tuning Server Parameters”.
An update statement is optimized like a
SELECT query with the
additional overhead of a write. The speed of the write depends
on the amount of data being updated and the number of indexes
that are updated. Indexes that are not changed do not get
updated.
Another way to get fast updates is to delay updates and then do many updates in a row later. Performing multiple updates together is much quicker than doing one at a time if you lock the table.
For a MyISAM table that uses dynamic row
format, updating a row to a longer total length may split the
row. If you do this often, it is very important to use
OPTIMIZE TABLE occasionally.
See Section 12.4.2.5, “OPTIMIZE TABLE Syntax”.
The time required to delete individual rows is exactly
proportional to the number of indexes. To delete rows more
quickly, you can increase the size of the key cache by
increasing the
key_buffer_size system
variable. See Section 7.9.2, “Tuning Server Parameters”.
To delete all rows from a table, TRUNCATE TABLE
is faster than
than tbl_nameDELETE FROM
. Truncate
operations are not transaction-safe; an error occurs when
attempting one in the course of an active transaction or
active table lock. See Section 12.2.10, “tbl_nameTRUNCATE TABLE Syntax”.
REPAIR TABLE for
MyISAM tables is similar to using
myisamchk for repair operations, and some
of the same performance optimizations apply:
myisamchck has variables that control memory allocation. You may be able to its improve performance by setting these variables, as described in Section 4.6.3.6, “myisamchk Memory Usage”.
For REPAIR TABLE, the same
principle applies, but because the repair is done by the
server, you set server system variables instead of
myisamchk variables. Also, In addition
to setting memory-allocation variables, increasing the
myisam_max_sort_file_size
system variable increases the likelihood that the repair
will use the faster filesort method and avoid the slower
repair by key cache method. Set the variable to the
maximum file size for your system, after checking to be
sure that there is enough free space to hold a copy of the
table files. The free space must be available in the file
system containing the original table files.
Suppose that a myisamchk table-repair operation is done using the following options to set its memory-allocation variables:
--key_buffer_size=128M --sort_buffer_size=256M --read_buffer_size=64M --write_buffer_size=64M
Some of those myisamchk variables correspond to server system variables:
| myisamchk Variable | System Variable |
|---|---|
key_buffer_size | key_buffer_size |
sort_buffer_size | myisam_sort_buffer_size |
read_buffer_size | read_buffer_size |
write_buffer_size | none |
Each of the server system variables can be set at runtime, and
some of them
(myisam_sort_buffer_size,
read_buffer_size) have a
session value in addition to a global value. Setting a session
value limits the effect of the change to your current session
and does not affect other users. Changing a global-only
variable (key_buffer_size,
myisam_max_sort_file_size)
affects other users as well. For
key_buffer_size, you must
take into account that the buffer is shared with those users.
For example, if you set the myisamchk
key_buffer_size variable to 128MB, you
could set the corresponding
key_buffer_size system
variable larger than that (if it is not already set larger),
to permit key buffer use by activity in other sessions.
However, changing the global key buffer size invalidates the
buffer, causing increased disk I/O and slowdown for other
sessions. An alternative that avoids this problem is to use a
separate key cache, assign to it the indexes from the table to
be repaired, and deallocate it when the repair is complete.
See Section 7.6.1.2, “Multiple Key Caches”.
Based on the preceding remarks, a REPAIR
TABLE operation can be done as follows to use
settings similar to the myisamchk command.
Here a separate 128MB key buffer is allocated and the file
system is assumed to permit a file size of at least 100GB.
SET SESSION myisam_sort_buffer_size = 256*1024*1024; SET SESSION read_buffer_size = 64*1024*1024; SET GLOBAL myisam_max_sort_file_size = 100*1024*1024*1024; SET GLOBAL repair_cache.key_buffer_size = 128*1024*1024; CACHE INDEXtbl_nameIN repair_cache; LOAD INDEX INTO CACHEtbl_name; REPAIR TABLEtbl_name; SET GLOBAL repair_cache.key_buffer_size = 0;
If you intend to change a global variable but want to do so
only for the duration of a REPAIR
TABLE operation to minimally affect other users,
save its value in a user variable and restore it afterward.
For example:
SET @old_myisam_sort_buffer_size = @@global.myisam_max_sort_file_size; SET GLOBAL myisam_max_sort_file_size = 100*1024*1024*1024; REPAIR TABLE tbl_name ; SET GLOBAL myisam_max_sort_file_size = @old_myisam_max_sort_file_size;
The system variables that affect REPAIR
TABLE can be set globally at server startup if you
want the values to be in effect by default. For example, add
these lines to the server my.cnf file:
[mysqld] myisam_sort_buffer_size=256M key_buffer_size=1G myisam_max_sort_file_size=100G
These settings do not include
read_buffer_size. Setting
read_buffer_size globally to
a large value does so for all sessions and can cause
performance to suffer due to excessive memory allocation for a
server with many simultaneous sessions.
As of MySQL 5.1.21, the implementation of
INFORMATION_SCHEMA is such that certain types
of queries for INFORMATION_SCHEMA tables can
be optimized to execute more quickly. This section provides
guidelines on writing queries that take advantage of these
optimizations. In general, the strategies outlined here minimize
the need for the server to access the file system to obtain the
information that makes up the contents of
INFORMATION_SCHEMA tables. By writing queries
that enable the server to avoid directory scans or opening table
files, you will obtain better performance. These optimizations
do have an effect on how collations are used for searches in
INFORMATION_SCHEMA tables. For more
information, see
Section 9.1.7.9, “Collation and INFORMATION_SCHEMA Searches”.
1) Try to use constant lookup values for
database and table names in the WHERE
clause
You can take advantage of this principle as follows:
To look up databases or tables, use expressions that evaluate to a constant, such as literal values, functions that return a constant, or scalar subqueries.
Avoid queries that use a nonconstant database name lookup value (or no lookup value) because they require a scan of the data directory to find matching database directory names.
Within a database, avoid queries that use a nonconstant table name lookup value (or no lookup value) because they require a scan of the database directory to find matching table files.
This principle applies to the
INFORMATION_SCHEMA tables shown in the
following table, which shows the columns for which a constant
lookup value enables the server to avoid a directory scan. For
example, if you are selecting from
TABLES, using a constant lookup
value for TABLE_SCHEMA in the
WHERE clause enables a data directory scan to
be avoided.
| Table | Column to specify to avoid data directory scan | Column to specify to avoid database directory scan |
|---|---|---|
COLUMNS | TABLE_SCHEMA | TABLE_NAME |
KEY_COLUMN_USAGE | TABLE_SCHEMA | TABLE_NAME |
PARTITIONS | TABLE_SCHEMA | TABLE_NAME |
REFERENTIAL_CONSTRAINTS | CONSTRAINT_SCHEMA | TABLE_NAME |
STATISTICS | TABLE_SCHEMA | TABLE_NAME |
TABLES | TABLE_SCHEMA | TABLE_NAME |
TABLE_CONSTRAINTS | TABLE_SCHEMA | TABLE_NAME |
TRIGGERS | EVENT_OBJECT_SCHEMA | EVENT_OBJECT_TABLE |
VIEWS | TABLE_SCHEMA | TABLE_NAME |
The benefit of a query that is limited to a specific constant database name is that checks need be made only for the named database directory. Example:
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test';
Use of the literal database name test enables
the server to check only the test database
directory, regardless of how many databases there might be. By
contrast, the following query is less efficient because it
requires a scan of the data directory to determine which
database names match the pattern 'test%':
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA LIKE 'test%';
For a query that is limited to a specific constant table name, checks need be made only for the named table within the corresponding database directory. Example:
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME = 't1';
Use of the literal table name t1 enables the
server to check only the files for the t1
table, regardless of how many tables there might be in the
test database. By contrast, the following
query requires a scan of the test database
directory to determine which table names match the pattern
't%':
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME LIKE 't%';
The following query requires a scan of the database directory to
determine matching database names for the pattern
'test%', and for each matching database, it
requires a scan of the database directory to determine matching
table names for the pattern 't%':
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test%' AND TABLE_NAME LIKE 't%';
2) Write queries that minimize the number of table files that must be opened
For queries that refer to certain
INFORMATION_SCHEMA table columns, several
optimizations are available that minimize the number of table
files that must be opened. Example:
SELECT TABLE_NAME, ENGINE FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test';
In this case, after the server has scanned the database
directory to determine the names of the tables in the database,
those names become available with no further file system
lookups. Thus, TABLE_NAME requires no files
to be opened. The ENGINE (storage engine)
value can be determined by opening the table's
.frm file, without touching other table
files such as the .MYD or
.MYI file.
Some values, such as INDEX_LENGTH for
MyISAM tables, require opening the
.MYD or .MYI file as
well.
The file-opening optimization types are denoted thus:
SKIP_OPEN_TABLE: Table files do not need
to be opened. The information has already become available
within the query by scanning the database directory.
OPEN_FRM_ONLY: Only the table's
.frm file need be opened.
OPEN_TRIGGER_ONLY: Only the table's
.TRG file need be opened.
OPEN_FULL_TABLE: The unoptimized
information lookup. The .frm,
.MYD, and .MYI
files must be opened.
The following list indicates how the preceding optimization
types apply to INFORMATION_SCHEMA table
columns. For tables and columns not named, none of the
optimizations apply.
COLUMNS:
OPEN_FRM_ONLY applies to all columns
KEY_COLUMN_USAGE:
OPEN_FULL_TABLE applies to all columns
PARTITIONS:
OPEN_FULL_TABLE applies to all columns
REFERENTIAL_CONSTRAINTS:
OPEN_FULL_TABLE applies to all columns
| Column | Optimization type |
|---|---|
TABLE_CATALOG | OPEN_FRM_ONLY |
TABLE_SCHEMA | OPEN_FRM_ONLY |
TABLE_NAME | OPEN_FRM_ONLY |
NON_UNIQUE | OPEN_FRM_ONLY |
INDEX_SCHEMA | OPEN_FRM_ONLY |
INDEX_NAME | OPEN_FRM_ONLY |
SEQ_IN_INDEX | OPEN_FRM_ONLY |
COLUMN_NAME | OPEN_FRM_ONLY |
COLLATION | OPEN_FRM_ONLY |
CARDINALITY | OPEN_FULL_TABLE |
SUB_PART | OPEN_FRM_ONLY |
PACKED | OPEN_FRM_ONLY |
NULLABLE | OPEN_FRM_ONLY |
INDEX_TYPE | OPEN_FULL_TABLE |
COMMENT | OPEN_FRM_ONLY |
| Column | Optimization type |
|---|---|
TABLE_CATALOG | SKIP_OPEN_TABLE |
TABLE_SCHEMA | SKIP_OPEN_TABLE |
TABLE_NAME | SKIP_OPEN_TABLE |
TABLE_TYPE | OPEN_FRM_ONLY |
ENGINE | OPEN_FRM_ONLY |
VERSION | OPEN_FRM_ONLY |
ROW_FORMAT | OPEN_FULL_TABLE |
TABLE_ROWS | OPEN_FULL_TABLE |
AVG_ROW_LENGTH | OPEN_FULL_TABLE |
DATA_LENGTH | OPEN_FULL_TABLE |
MAX_DATA_LENGTH | OPEN_FULL_TABLE |
INDEX_LENGTH | OPEN_FULL_TABLE |
DATA_FREE | OPEN_FULL_TABLE |
AUTO_INCREMENT | OPEN_FULL_TABLE |
CREATE_TIME | OPEN_FULL_TABLE |
UPDATE_TIME | OPEN_FULL_TABLE |
CHECK_TIME | OPEN_FULL_TABLE |
TABLE_COLLATION | OPEN_FRM_ONLY |
CHECKSUM | OPEN_FULL_TABLE |
CREATE_OPTIONS | OPEN_FRM_ONLY |
TABLE_COMMENT | OPEN_FRM_ONLY |
TABLE_CONSTRAINTS:
OPEN_FULL_TABLE applies to all columns
TRIGGERS:
OPEN_FULL_TABLE applies to all columns
| Column | Optimization type |
|---|---|
TABLE_CATALOG | OPEN_FRM_ONLY |
TABLE_SCHEMA | OPEN_FRM_ONLY |
TABLE_NAME | OPEN_FRM_ONLY |
VIEW_DEFINITION | OPEN_FULL_TABLE |
CHECK_OPTION | OPEN_FULL_TABLE |
IS_UPDATABLE | OPEN_FULL_TABLE |
DEFINER | OPEN_FULL_TABLE |
SECURITY_TYPE | OPEN_FULL_TABLE |
CHARACTER_SET_CLIENT | OPEN_FULL_TABLE |
COLLATION_CONNECTION | OPEN_FULL_TABLE |
3) Use
EXPLAIN to determine whether the
server can use INFORMATION_SCHEMA
optimizations for a query
This applies particularly for
INFORMATION_SCHEMA queries that search for
information from more than one database, which might take a long
time and impact performance. The Extra value
in EXPLAIN output indicates
which, if any, of the optimizations described earlier the server
can use to evaluate INFORMATION_SCHEMA
queries. The following examples demonstrate the kinds of
information you can expect to see in the
Extra value.
mysql>EXPLAIN SELECT TABLE_NAME FROM INFORMATION_SCHEMA.VIEWS WHERE->TABLE_SCHEMA = 'test' AND TABLE_NAME = 'v1'\G*************************** 1. row *************************** id: 1 select_type: SIMPLE table: VIEWS type: ALL possible_keys: NULL key: TABLE_SCHEMA,TABLE_NAME key_len: NULL ref: NULL rows: NULL Extra: Using where; Open_frm_only; Scanned 0 databases
Use of constant database and table lookup values enables the
server to avoid directory scans. For references to
VIEWS.TABLE_NAME, only the
.frm file need be opened.
mysql> EXPLAIN SELECT TABLE_NAME, ROW_FORMAT FROM INFORMATION_SCHEMA.TABLES\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: TABLES
type: ALL
possible_keys: NULL
key: NULL
key_len: NULL
ref: NULL
rows: NULL
Extra: Open_full_table; Scanned all databases
No lookup values are provided (there is no
WHERE clause), so the server must scan the
data directory and each database directory. For each table thus
identified, the table name and row format are selected.
TABLE_NAME requires no further table files to
be opened (the SKIP_OPEN_TABLE optimization
applies). ROW_FORMAT requires all table files
to be opened (OPEN_FULL_TABLE applies).
EXPLAIN reports
OPEN_FULL_TABLE because it is more expensive
than SKIP_OPEN_TABLE.
mysql>EXPLAIN SELECT TABLE_NAME, TABLE_TYPE FROM INFORMATION_SCHEMA.TABLES->WHERE TABLE_SCHEMA = 'test'\G*************************** 1. row *************************** id: 1 select_type: SIMPLE table: TABLES type: ALL possible_keys: NULL key: TABLE_SCHEMA key_len: NULL ref: NULL rows: NULL Extra: Using where; Open_frm_only; Scanned 1 database
No table name lookup value is provided, so the server must scan
the test database directory. For the
TABLE_NAME and TABLE_TYPE
columns, the SKIP_OPEN_TABLE and
OPEN_FRM_ONLY optimizations apply,
respectively. EXPLAIN reports
OPEN_FRM_ONLY because it is more expensive.
mysql>EXPLAIN SELECT B.TABLE_NAME->FROM INFORMATION_SCHEMA.TABLES AS A, INFORMATION_SCHEMA.COLUMNS AS B->WHERE A.TABLE_SCHEMA = 'test'->AND A.TABLE_NAME = 't1'->AND B.TABLE_NAME = A.TABLE_NAME\G*************************** 1. row *************************** id: 1 select_type: SIMPLE table: A type: ALL possible_keys: NULL key: TABLE_SCHEMA,TABLE_NAME key_len: NULL ref: NULL rows: NULL Extra: Using where; Skip_open_table; Scanned 0 databases *************************** 2. row *************************** id: 1 select_type: SIMPLE table: B type: ALL possible_keys: NULL key: NULL key_len: NULL ref: NULL rows: NULL Extra: Using where; Open_frm_only; Scanned all databases; Using join buffer
For the first EXPLAIN output row:
Constant database and table lookup values enable the server to
avoid directory scans for TABLES values.
References to TABLES.TABLE_NAME require no
further table files.
For the second EXPLAIN output
row: All COLUMNS table values are
OPEN_FRM_ONLY lookups, so
COLUMNS.TABLE_NAME requires the
.frm file to be opened.
mysql> EXPLAIN SELECT * FROM INFORMATION_SCHEMA.COLLATIONS\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: COLLATIONS
type: ALL
possible_keys: NULL
key: NULL
key_len: NULL
ref: NULL
rows: NULL
Extra:
In this case, no optimizations apply because
COLLATIONS is not one of the
INFORMATION_SCHEMA tables for which
optimizations are available.
This section lists a number of miscellaneous tips for improving query processing speed:
Use persistent connections to the database to avoid
connection overhead. If you cannot use persistent
connections and you are initiating many new connections to
the database, you may want to change the value of the
thread_cache_size variable.
See Section 7.9.2, “Tuning Server Parameters”.
Always check whether all your queries really use the indexes
that you have created in the tables. In MySQL, you can do
this with the EXPLAIN
statement. See Section 7.2.1, “Optimizing Queries with EXPLAIN”.
Try to avoid complex SELECT
queries on MyISAM tables that are updated
frequently, to avoid problems with table locking that occur
due to contention between readers and writers.
MyISAM supports concurrent inserts: If a
table has no free blocks in the middle of the data file, you
can INSERT new rows into it
at the same time that other threads are reading from the
table. If it is important to be able to do this, you should
consider using the table in ways that avoid deleting rows.
Another possibility is to run OPTIMIZE
TABLE to defragment the table after you have
deleted a lot of rows from it. This behavior is altered by
setting the
concurrent_insert variable.
You can force new rows to be appended (and therefore permit
concurrent inserts), even in tables that have deleted rows.
See Section 7.7.3, “Concurrent Inserts”.
To fix any compression issues that may have occurred with
ARCHIVE tables, you can use
OPTIMIZE TABLE. See
Section 13.12, “The ARCHIVE Storage Engine”.
Use ALTER TABLE ... ORDER BY
if you
usually retrieve rows in
expr1,
expr2, ... order. By
using this option after extensive changes to the table, you
may be able to get higher performance.
expr1,
expr2, ...
In some cases, it may make sense to introduce a column that is “hashed” based on information from other columns. If this column is short, reasonably unique, and indexed, it may be much faster than a “wide” index on many columns. In MySQL, it is very easy to use this extra column:
SELECT * FROMtbl_nameWHEREhash_col=MD5(CONCAT(col1,col2)) ANDcol1='constant' ANDcol2='constant';
For MyISAM tables that change frequently,
you should try to avoid all variable-length columns
(VARCHAR,
BLOB, and
TEXT). The table uses dynamic
row format if it includes even a single variable-length
column. See Chapter 13, Storage Engines.
It is normally not useful to split a table into different
tables just because the rows become large. In accessing a
row, the biggest performance hit is the disk seek needed to
find the first byte of the row. After finding the data, most
modern disks can read the entire row fast enough for most
applications. The only cases where splitting up a table
makes an appreciable difference is if it is a
MyISAM table using dynamic row format
that you can change to a fixed row size, or if you very
often need to scan the table but do not need most of the
columns. See Chapter 13, Storage Engines.
If you often need to calculate results such as counts based on information from a lot of rows, it may be preferable to introduce a new table and update the counter in real time. An update of the following form is very fast:
UPDATEtbl_nameSETcount_col=count_col+1 WHEREkey_col=constant;
This is very important when you use MySQL storage engines
such as MyISAM that has only table-level
locking (multiple readers with single writers). This also
gives better performance with most database systems, because
the row locking manager in this case has less to do.
If you need to collect statistics from large log tables, use summary tables instead of scanning the entire log table. Maintaining the summaries should be much faster than trying to calculate statistics “live.” Regenerating new summary tables from the logs when things change (depending on business decisions) is faster than changing the running application.
If possible, you should classify reports as “live” or as “statistical,” where data needed for statistical reports is created only from summary tables that are generated periodically from the live data.
Take advantage of the fact that columns have default values. Insert values explicitly only when the value to be inserted differs from the default. This reduces the parsing that MySQL must do and improves the insert speed.
In some cases, it is convenient to pack and store data into
a BLOB column. In this case,
you must provide code in your application to pack and unpack
information, but this may save a lot of accesses at some
stage. This is practical when you have data that does not
conform well to a rows-and-columns table structure.
Normally, you should try to keep all data nonredundant (observing what is referred to in database theory as third normal form). However, there may be situations in which it can be advantageous to duplicate information or create summary tables to gain more speed.
Stored routines or UDFs (user-defined functions) may be a good way to gain performance for some tasks. See Section 19.2, “Using Stored Routines (Procedures and Functions)”, and Section 22.3, “Adding New Functions to MySQL”, for more information.
You can increase performance by caching queries or answers in your application and then executing many inserts or updates together. If your database system supports table locks, this should help to ensure that the index cache is only flushed once after all updates. You can also take advantage of MySQL's query cache to achieve similar results; see Section 7.6.3, “The MySQL Query Cache”.
Use INSERT DELAYED when you
do not need to know when your data is written. This reduces
the overall insertion impact because many rows can be
written with a single disk write.
Use INSERT LOW_PRIORITY when you want to
give SELECT statements higher
priority than your inserts.
Use SELECT HIGH_PRIORITY to get
retrievals that jump the queue. That is, the
SELECT is executed even if
there is another client waiting to do a write.
LOW_PRIORITY and
HIGH_PRIORITY have an effect only for
storage engines that use only table-level locking (such as
MyISAM, MEMORY, and
MERGE).
Use multiple-row INSERT
statements to store many rows with one SQL statement. Many
SQL servers support this, including MySQL.
Use LOAD DATA
INFILE to load large amounts of data. This is
faster than using INSERT
statements.
Use AUTO_INCREMENT columns so that each
row in a table can be identified by a single unique value.
unique values.
Use OPTIMIZE TABLE once in a
while to avoid fragmentation with dynamic-format
MyISAM tables. See
Section 13.5.3, “MyISAM Table Storage Formats”.
Use MEMORY tables when possible to get
more speed. See Section 13.9, “The MEMORY Storage Engine”.
MEMORY tables are useful for noncritical
data that is accessed often, such as information about the
last displayed banner for users who don't have cookies
enabled in their Web browser. User sessions are another
alternative available in many Web application environments
for handling volatile state data.
With Web servers, images and other binary assets should normally be stored as files. That is, store only a reference to the file rather than the file itself in the database. Most Web servers are better at caching files than database contents, so using files is generally faster.
Columns with identical information in different tables should be declared to have identical data types so that joins based on the corresponding columns will be faster.
Try to keep column names simple. For example, in a table
named customer, use a column name of
name instead of
customer_name. To make your names
portable to other SQL servers, you should keep them shorter
than 18 characters.
If you need really high speed, you should take a look at the
low-level interfaces for data storage that the different SQL
servers support. For example, by accessing the MySQL
MyISAM storage engine directly, you could
get a speed increase of two to five times compared to using
the SQL interface. To be able to do this, the data must be
on the same server as the application, and usually it should
only be accessed by one process (because external file
locking is really slow). One could eliminate these problems
by introducing low-level MyISAM commands
in the MySQL server (this could be one easy way to get more
performance if needed). By carefully designing the database
interface, it should be quite easy to support this type of
optimization.
If you are using numeric data, it is faster in many cases to access information from a database (using a live connection) than to access a text file. Information in the database is likely to be stored in a more compact format than in the text file, so accessing it involves fewer disk accesses. You also save code in your application because you need not parse your text files to find line and column boundaries.
Replication can provide a performance benefit for some operations. You can distribute client retrievals among replication servers to split up the load. To avoid slowing down the master while making backups, you can make backups using a slave server. See Chapter 16, Replication.
Declaring a MyISAM table with the
DELAY_KEY_WRITE=1 table option makes
index updates faster because they are not flushed to disk
until the table is closed. The downside is that if something
kills the server while such a table is open, you should
ensure that the table is okay by running the server with the
--myisam-recover option, or
by running myisamchk before restarting
the server. (However, even in this case, you should not lose
anything by using DELAY_KEY_WRITE,
because the key information can always be generated from the
data rows.)
MySQL provides optimizer control through system variables that affect how query plans are evaluated and which switchable optimizations are enabled.
The task of the query optimizer is to find an optimal plan for executing an SQL query. Because the difference in performance between “good” and “bad” plans can be orders of magnitude (that is, seconds versus hours or even days), most query optimizers, including that of MySQL, perform a more or less exhaustive search for an optimal plan among all possible query evaluation plans. For join queries, the number of possible plans investigated by the MySQL optimizer grows exponentially with the number of tables referenced in a query. For small numbers of tables (typically less than 7 to 10) this is not a problem. However, when larger queries are submitted, the time spent in query optimization may easily become the major bottleneck in the server's performance.
A more flexible method for query optimization enables the user to control how exhaustive the optimizer is in its search for an optimal query evaluation plan. The general idea is that the fewer plans that are investigated by the optimizer, the less time it spends in compiling a query. On the other hand, because the optimizer skips some plans, it may miss finding an optimal plan.
The behavior of the optimizer with respect to the number of plans it evaluates can be controlled using two system variables:
The optimizer_prune_level
variable tells the optimizer to skip certain plans based on
estimates of the number of rows accessed for each table. Our
experience shows that this kind of “educated
guess” rarely misses optimal plans, and may
dramatically reduce query compilation times. That is why
this option is on
(optimizer_prune_level=1) by default.
However, if you believe that the optimizer missed a better
query plan, this option can be switched off
(optimizer_prune_level=0) with the risk
that query compilation may take much longer. Note that, even
with the use of this heuristic, the optimizer still explores
a roughly exponential number of plans.
The optimizer_search_depth
variable tells how far into the “future” of
each incomplete plan the optimizer should look to evaluate
whether it should be expanded further. Smaller values of
optimizer_search_depth may
result in orders of magnitude smaller query compilation
times. For example, queries with 12, 13, or more tables may
easily require hours and even days to compile if
optimizer_search_depth is
close to the number of tables in the query. At the same
time, if compiled with
optimizer_search_depth
equal to 3 or 4, the optimizer may compile in less than a
minute for the same query. If you are unsure of what a
reasonable value is for
optimizer_search_depth,
this variable can be set to 0 to tell the optimizer to
determine the value automatically.
The optimizer_switch system
variable enables control over optimizer behavior. Its value is a
set of flags, each of which has a value of on
or off to indicate whether the corresponding
optimizer behavior is enabled or disabled. This variable has
global and session values and can be changed at runtime. The
global default can be set at server startup.
To see the current set of optimizer flags, select the variable value:
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=on,
index_merge_sort_union=on,
index_merge_intersection=on
To change the value of
optimizer_switch, assign a
value consisting of a comma-separated list of one or more
commands:
SET [GLOBAL|SESSION] optimizer_switch='command[,command]...';
Each command value should have one of
the forms shown in the following table.
| Command Syntax | Meaning |
|---|---|
default | Reset every optimization to its default value |
| Set the named optimization to its default value |
| Disable the named optimization |
| Enable the named optimization |
The order of the commands in the value does not matter, although
the default command is executed first if
present. Setting an opt_name flag to
default sets it to whichever of
on or off is its default
value. Specifying any given opt_name
more than once in the value is not permitted and causes an
error. Any errors in the value cause the assignment to fail with
an error and the value of
optimizer_switch remains
unchanged.
The following table lists the permissible
opt_name flag names.
| Flag Name | Meaning |
|---|---|
index_merge | Controls all Index Merge optimizations |
index_merge_intersection | Controls the Index Merge Intersection Access optimization |
index_merge_sort_union | Controls the Index Merge Sort-Union Access optimization |
index_merge_union | Controls the Index Merge Union Access optimization |
For information about Index Merge, see Section 7.3.1.4, “Index Merge Optimization”.
When you assign a value to
optimizer_switch, flags that
are not mentioned keep their current values. This makes it
possible to enable or disable specific optimizer behaviors in a
single statement without affecting other behaviors. The
statement does not depend on what other optimizer flags exist
and what their values are. Suppose that all Index Merge
optimizations are enabled:
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=on,
index_merge_sort_union=on,
index_merge_intersection=on
If the server is using the Index Merge Union or Index Merge Sort-Union access methods for certain queries and you want to check whether the optimizer will perform better without them, set the variable value like this:
mysql>SET optimizer_switch='index_merge_union=off,index_merge_sort_union=off';mysql>SELECT @@optimizer_switch\G*************************** 1. row *************************** @@optimizer_switch: index_merge=on,index_merge_union=off, index_merge_sort_union=off, index_merge_intersection=on
All MySQL data types can be indexed. Use of indexes on the
relevant columns is the best way to improve the performance of
SELECT operations.
The maximum number of indexes per table and the maximum index length is defined per storage engine. See Chapter 13, Storage Engines. All storage engines support at least 16 indexes per table and a total index length of at least 256 bytes. Most storage engines have higher limits.
With
syntax in an index specification, you can create an index that
uses only the first col_name(N)N characters of a
string column. Indexing only a prefix of column values in this
way can make the index file much smaller. When you index a
BLOB or
TEXT column, you
must specify a prefix length for the index.
For example:
CREATE TABLE test (blob_col BLOB, INDEX(blob_col(10)));
Prefixes can be up to 1000 bytes long (767 bytes for
InnoDB tables). Note that prefix limits are
measured in bytes, whereas the prefix length in
CREATE TABLE statements is
interpreted as number of characters. Be sure to take
this into account when specifying a prefix length for a column
that uses a multi-byte character set.
You can also create FULLTEXT indexes. These
are used for full-text searches. Only the
MyISAM storage engine supports
FULLTEXT indexes and only for
CHAR,
VARCHAR, and
TEXT columns. Indexing always
takes place over the entire column and column prefix indexing is
not supported. For details, see
Section 11.9, “Full-Text Search Functions”.
You can also create indexes on spatial data types. Currently,
only MyISAM supports R-tree indexes on
spatial types. Other storage engines use B-trees for indexing
spatial types (except for ARCHIVE and
NDBCLUSTER, which do not support
spatial type indexing).
The MEMORY storage engine uses
HASH indexes by default, but also supports
BTREE indexes.
MySQL can create composite indexes (that is, indexes on multiple columns). An index may consist of up to 16 columns. For certain data types, you can index a prefix of the column (see Section 7.5.1, “Column Indexes”).
A multiple-column index can be considered a sorted array containing values that are created by concatenating the values of the indexed columns.
MySQL uses multiple-column indexes in such a way that queries
are fast when you specify a known quantity for the first column
of the index in a WHERE clause, even if you
do not specify values for the other columns.
Suppose that a table has the following specification:
CREATE TABLE test (
id INT NOT NULL,
last_name CHAR(30) NOT NULL,
first_name CHAR(30) NOT NULL,
PRIMARY KEY (id),
INDEX name (last_name,first_name)
);
The name index is an index over the
last_name and first_name
columns. The index can be used for queries that specify values
in a known range for last_name, or for both
last_name and first_name.
Therefore, the name index is used in the
following queries:
SELECT * FROM test WHERE last_name='Widenius'; SELECT * FROM test WHERE last_name='Widenius' AND first_name='Michael'; SELECT * FROM test WHERE last_name='Widenius' AND (first_name='Michael' OR first_name='Monty'); SELECT * FROM test WHERE last_name='Widenius' AND first_name >='M' AND first_name < 'N';
However, the name index is
not used in the following queries:
SELECT * FROM test WHERE first_name='Michael'; SELECT * FROM test WHERE last_name='Widenius' OR first_name='Michael';
The manner in which MySQL uses indexes to improve query performance is discussed further in Section 7.5.3, “How MySQL Uses Indexes”.
Indexes are used to find rows with specific column values quickly. Without an index, MySQL must begin with the first row and then read through the entire table to find the relevant rows. The larger the table, the more this costs. If the table has an index for the columns in question, MySQL can quickly determine the position to seek to in the middle of the data file without having to look at all the data. If a table has 1,000 rows, this is at least 100 times faster than reading sequentially. If you need to access most of the rows, it is faster to read sequentially, because this minimizes disk seeks.
Most MySQL indexes (PRIMARY KEY,
UNIQUE, INDEX, and
FULLTEXT) are stored in B-trees. Exceptions
are that indexes on spatial data types use R-trees, and that
MEMORY tables also support hash indexes.
Strings are automatically prefix- and end-space compressed. See
Section 12.1.13, “CREATE INDEX Syntax”.
In general, indexes are used as described in the following
discussion. Characteristics specific to hash indexes (as used in
MEMORY tables) are described at the end of
this section.
MySQL uses indexes for these operations:
To find the rows matching a WHERE clause
quickly.
To eliminate rows from consideration. If there is a choice between multiple indexes, MySQL normally uses the index that finds the smallest number of rows.
To retrieve rows from other tables when performing joins.
MySQL can use indexes on columns more efficiently if they
are declared as the same type and size. In this context,
VARCHAR and
CHAR are considered the same
if they are declared as the same size. For example,
VARCHAR(10) and
CHAR(10) are the same size, but
VARCHAR(10) and
CHAR(15) are not.
Comparison of dissimilar columns may prevent use of indexes
if values cannot be compared directly without conversion.
Suppose that a numeric column is compared to a string
column. For a given value such as 1 in
the numeric column, it might compare equal to any number of
values in the string column such as '1',
' 1', '00001', or
'01.e1'. This rules out use of any
indexes for the string column.
To find the MIN() or
MAX() value for a specific
indexed column key_col. This is
optimized by a preprocessor that checks whether you are
using WHERE on all key
parts that occur before key_part_N =
constantkey_col
in the index. In this case, MySQL does a single key lookup
for each MIN() or
MAX() expression and replaces
it with a constant. If all expressions are replaced with
constants, the query returns at once. For example:
SELECT MIN(key_part2),MAX(key_part2) FROMtbl_nameWHEREkey_part1=10;
To sort or group a table if the sorting or grouping is done
on a leftmost prefix of a usable key (for example,
ORDER BY ). If all key
parts are followed by key_part1,
key_part2DESC, the key is
read in reverse order. See
Section 7.3.1.11, “ORDER BY Optimization”, and
Section 7.3.1.12, “GROUP BY Optimization”.
In some cases, a query can be optimized to retrieve values without consulting the data rows. If a query uses only columns from a table that are numeric and that form a leftmost prefix for some key, the selected values may be retrieved from the index tree for greater speed:
SELECTkey_part3FROMtbl_nameWHEREkey_part1=1
Suppose that you issue the following
SELECT statement:
mysql> SELECT * FROM tbl_name WHERE col1=val1 AND col2=val2;
If a multiple-column index exists on col1 and
col2, the appropriate rows can be fetched
directly. If separate single-column indexes exist on
col1 and col2, the
optimizer will attempt to use the Index Merge optimization (see
Section 7.3.1.4, “Index Merge Optimization”), or attempt to find
the most restrictive index by deciding which index finds fewer
rows and using that index to fetch the rows.
If the table has a multiple-column index, any leftmost prefix of
the index can be used by the optimizer to find rows. For
example, if you have a three-column index on (col1,
col2, col3), you have indexed search capabilities on
(col1), (col1, col2), and
(col1, col2, col3).
MySQL cannot use an index if the columns do not form a leftmost
prefix of the index. Suppose that you have the
SELECT statements shown here:
SELECT * FROMtbl_nameWHERE col1=val1; SELECT * FROMtbl_nameWHERE col1=val1AND col2=val2; SELECT * FROMtbl_nameWHERE col2=val2; SELECT * FROMtbl_nameWHERE col2=val2AND col3=val3;
If an index exists on (col1, col2, col3),
only the first two queries use the index. The third and fourth
queries do involve indexed columns, but
(col2) and (col2, col3)
are not leftmost prefixes of (col1, col2,
col3).
A B-tree index can be used for column comparisons in expressions
that use the =,
>,
>=,
<,
<=,
or BETWEEN operators. The index
also can be used for LIKE
comparisons if the argument to LIKE
is a constant string that does not start with a wildcard
character. For example, the following
SELECT statements use indexes:
SELECT * FROMtbl_nameWHEREkey_colLIKE 'Patrick%'; SELECT * FROMtbl_nameWHEREkey_colLIKE 'Pat%_ck%';
In the first statement, only rows with 'Patrick' <=
are
considered. In the second statement, only rows with
key_col < 'Patricl''Pat' <= are considered.
key_col <
'Pau'
The following SELECT statements
do not use indexes:
SELECT * FROMtbl_nameWHEREkey_colLIKE '%Patrick%'; SELECT * FROMtbl_nameWHEREkey_colLIKEother_col;
In the first statement, the LIKE
value begins with a wildcard character. In the second statement,
the LIKE value is not a constant.
If you use ... LIKE
'% and
string%'string is longer than three
characters, MySQL uses the Turbo Boyer-Moore
algorithm to initialize the pattern for the string
and then uses this pattern to perform the search more quickly.
A search using employs indexes if
col_name IS
NULLcol_name is indexed.
Any index that does not span all
AND levels in the
WHERE clause is not used to optimize the
query. In other words, to be able to use an index, a prefix of
the index must be used in every AND
group.
The following WHERE clauses use indexes:
... WHEREindex_part1=1 ANDindex_part2=2 ANDother_column=3 /*index= 1 ORindex= 2 */ ... WHEREindex=1 OR A=10 ANDindex=2 /* optimized like "index_part1='hello'" */ ... WHEREindex_part1='hello' ANDindex_part3=5 /* Can use index onindex1but not onindex2orindex3*/ ... WHEREindex1=1 ANDindex2=2 ORindex1=3 ANDindex3=3;
These WHERE clauses do
not use indexes:
/*index_part1is not used */ ... WHEREindex_part2=1 ANDindex_part3=2 /* Index is not used in both parts of the WHERE clause */ ... WHEREindex=1 OR A=10 /* No index spans all rows */ ... WHEREindex_part1=1 ORindex_part2=10
Sometimes MySQL does not use an index, even if one is available.
One circumstance under which this occurs is when the optimizer
estimates that using the index would require MySQL to access a
very large percentage of the rows in the table. (In this case, a
table scan is likely to be much faster because it requires fewer
seeks.) However, if such a query uses LIMIT
to retrieve only some of the rows, MySQL uses an index anyway,
because it can much more quickly find the few rows to return in
the result.
Hash indexes have somewhat different characteristics from those just discussed:
They are used only for equality comparisons that use the
= or <=>
operators (but are very fast). They are
not used for comparison operators such as
< that find a range of values.
The optimizer cannot use a hash index to speed up
ORDER BY operations. (This type of index
cannot be used to search for the next entry in order.)
MySQL cannot determine approximately how many rows there are
between two values (this is used by the range optimizer to
decide which index to use). This may affect some queries if
you change a MyISAM table to a
hash-indexed MEMORY table.
Only whole keys can be used to search for a row. (With a B-tree index, any leftmost prefix of the key can be used to find rows.)
Storage engines collect statistics about tables for use by the optimizer. Table statistics are based on value groups, where a value group is a set of rows with the same key prefix value. For optimizer purposes, an important statistic is the average value group size.
MySQL uses the average value group size in the following ways:
To estimate how may rows must be read for each
ref access
To estimate how many row a partial join will produce; that is, the number of rows that an operation of this form will produce:
(...) JOINtbl_nameONtbl_name.key=expr
As the average value group size for an index increases, the index is less useful for those two purposes because the average number of rows per lookup increases: For the index to be good for optimization purposes, it is best that each index value target a small number of rows in the table. When a given index value yields a large number of rows, the index is less useful and MySQL is less likely to use it.
The average value group size is related to table cardinality,
which is the number of value groups. The
SHOW INDEX statement displays a
cardinality value based on
N/S, where
N is the number of rows in the table
and S is the average value group
size. That ratio yields an approximate number of value groups in
the table.
For a join based on the <=> comparison
operator, NULL is not treated differently
from any other value: NULL <=> NULL,
just as for any other
N <=>
NN.
However, for a join based on the = operator,
NULL is different from
non-NULL values:
is not true when
expr1 =
expr2expr1 or
expr2 (or both) are
NULL. This affects
ref accesses for comparisons
of the form : MySQL will not access
the table if the current value of
tbl_name.key =
exprexpr is NULL,
because the comparison cannot be true.
For = comparisons, it does not matter how
many NULL values are in the table. For
optimization purposes, the relevant value is the average size of
the non-NULL value groups. However, MySQL
does not currently enable that average size to be collected or
used.
For MyISAM tables, you have some control over
collection of table statistics by means of the
myisam_stats_method system
variable. This variable has three possible values, which differ
as follows:
When myisam_stats_method is
nulls_equal, all NULL
values are treated as identical (that is, they all form a
single value group).
If the NULL value group size is much
higher than the average non-NULL value
group size, this method skews the average value group size
upward. This makes index appear to the optimizer to be less
useful than it really is for joins that look for
non-NULL values. Consequently, the
nulls_equal method may cause the
optimizer not to use the index for
ref accesses when it
should.
When myisam_stats_method is
nulls_unequal, NULL
values are not considered the same. Instead, each
NULL value forms a separate value group
of size 1.
If you have many NULL values, this method
skews the average value group size downward. If the average
non-NULL value group size is large,
counting NULL values each as a group of
size 1 causes the optimizer to overestimate the value of the
index for joins that look for non-NULL
values. Consequently, the nulls_unequal
method may cause the optimizer to use this index for
ref lookups when other
methods may be better.
When myisam_stats_method is
nulls_ignored, NULL
values are ignored.
If you tend to use many joins that use
<=> rather than =,
NULL values are not special in comparisons
and one NULL is equal to another. In this
case, nulls_equal is the appropriate
statistics method.
The myisam_stats_method system
variable has global and session values. Setting the global value
affects MyISAM statistics collection for all
MyISAM tables. Setting the session value
affects statistics collection only for the current client
connection. This means that you can force a table's statistics
to be regenerated with a given method without affecting other
clients by setting the session value of
myisam_stats_method.
To regenerate table statistics, you can use any of the following methods:
Change the table to cause its statistics to go out of date
(for example, insert a row and then delete it), and then set
myisam_stats_method and
issue an ANALYZE TABLE
statement
Some caveats regarding the use of
myisam_stats_method:
You can force table statistics to be collected explicitly,
as just described. However, MySQL may also collect
statistics automatically. For example, if during the course
of executing statements for a table, some of those
statements modify the table, MySQL may collect statistics.
(This may occur for bulk inserts or deletes, or some
ALTER TABLE statements, for
example.) If this happens, the statistics are collected
using whatever value
myisam_stats_method has at
the time. Thus, if you collect statistics using one method,
but myisam_stats_method is
set to the other method when a table's statistics are
collected automatically later, the other method will be
used.
There is no way to tell which method was used to generate
statistics for a given MyISAM table.
myisam_stats_method applies
only to MyISAM tables. Other storage
engines have only one method for collecting table
statistics. Usually it is closer to the
nulls_equal method.
MySQL uses several strategies that cache information in memory buffers to increase performance.
To minimize disk I/O, the MyISAM storage
engine exploits a strategy that is used by many database
management systems. It employs a cache mechanism to keep the
most frequently accessed table blocks in memory:
For index blocks, a special structure called the key cache (or key buffer) is maintained. The structure contains a number of block buffers where the most-used index blocks are placed.
For data blocks, MySQL uses no special cache. Instead it relies on the native operating system file system cache.
This section first describes the basic operation of the
MyISAM key cache. Then it discusses features
that improve key cache performance and that enable you to better
control cache operation:
Multiple sessions can access the cache concurrently.
You can set up multiple key caches and assign table indexes to specific caches.
To control the size of the key cache, use the
key_buffer_size system
variable. If this variable is set equal to zero, no key cache is
used. The key cache also is not used if the
key_buffer_size value is too
small to allocate the minimal number of block buffers (8).
When the key cache is not operational, index files are accessed using only the native file system buffering provided by the operating system. (In other words, table index blocks are accessed using the same strategy as that employed for table data blocks.)
An index block is a contiguous unit of access to the
MyISAM index files. Usually the size of an
index block is equal to the size of nodes of the index B-tree.
(Indexes are represented on disk using a B-tree data structure.
Nodes at the bottom of the tree are leaf nodes. Nodes above the
leaf nodes are nonleaf nodes.)
All block buffers in a key cache structure are the same size. This size can be equal to, greater than, or less than the size of a table index block. Usually one these two values is a multiple of the other.
When data from any table index block must be accessed, the server first checks whether it is available in some block buffer of the key cache. If it is, the server accesses data in the key cache rather than on disk. That is, it reads from the cache or writes into it rather than reading from or writing to disk. Otherwise, the server chooses a cache block buffer containing a different table index block (or blocks) and replaces the data there by a copy of required table index block. As soon as the new index block is in the cache, the index data can be accessed.
If it happens that a block selected for replacement has been modified, the block is considered “dirty.” In this case, prior to being replaced, its contents are flushed to the table index from which it came.
Usually the server follows an LRU (Least Recently Used) strategy: When choosing a block for replacement, it selects the least recently used index block. To make this choice easier, the key cache module maintains all used blocks in a special list (LRU chain) ordered by time of use. When a block is accessed, it is the most recently used and is placed at the end of the list. When blocks need to be replaced, blocks at the beginning of the list are the least recently used and become the first candidates for eviction.
The InnoDB storage engine also uses an LRU
algorithm, to manage its buffer pool. See
Section 7.6.2, “The InnoDB Buffer Pool”.
Threads can access key cache buffers simultaneously, subject to the following conditions:
A buffer that is not being updated can be accessed by multiple sessions.
A buffer that is being updated causes sessions that need to use it to wait until the update is complete.
Multiple sessions can initiate requests that result in cache block replacements, as long as they do not interfere with each other (that is, as long as they need different index blocks, and thus cause different cache blocks to be replaced).
Shared access to the key cache enables the server to improve throughput significantly.
Shared access to the key cache improves performance but does not eliminate contention among sessions entirely. They still compete for control structures that manage access to the key cache buffers. To reduce key cache access contention further, MySQL also provides multiple key caches. This feature enables you to assign different table indexes to different key caches.
Where there are multiple key caches, the server must know
which cache to use when processing queries for a given
MyISAM table. By default, all
MyISAM table indexes are cached in the
default key cache. To assign table indexes to a specific key
cache, use the CACHE INDEX
statement (see Section 12.4.6.2, “CACHE INDEX Syntax”). For example,
the following statement assigns indexes from the tables
t1, t2, and
t3 to the key cache named
hot_cache:
mysql> CACHE INDEX t1, t2, t3 IN hot_cache;
+---------+--------------------+----------+----------+
| Table | Op | Msg_type | Msg_text |
+---------+--------------------+----------+----------+
| test.t1 | assign_to_keycache | status | OK |
| test.t2 | assign_to_keycache | status | OK |
| test.t3 | assign_to_keycache | status | OK |
+---------+--------------------+----------+----------+
The key cache referred to in a CACHE
INDEX statement can be created by setting its size
with a SET
GLOBAL parameter setting statement or by using
server startup options. For example:
mysql> SET GLOBAL keycache1.key_buffer_size=128*1024;
To destroy a key cache, set its size to zero:
mysql> SET GLOBAL keycache1.key_buffer_size=0;
Note that you cannot destroy the default key cache. Any attempt to do this will be ignored:
mysql>SET GLOBAL key_buffer_size = 0;mysql>SHOW VARIABLES LIKE 'key_buffer_size';+-----------------+---------+ | Variable_name | Value | +-----------------+---------+ | key_buffer_size | 8384512 | +-----------------+---------+
Key cache variables are structured system variables that have
a name and components. For
keycache1.key_buffer_size,
keycache1 is the cache variable name and
key_buffer_size is the cache
component. See Section 5.1.5.1, “Structured System Variables”,
for a description of the syntax used for referring to
structured key cache system variables.
By default, table indexes are assigned to the main (default) key cache created at the server startup. When a key cache is destroyed, all indexes assigned to it are reassigned to the default key cache.
For a busy server, you can use a strategy that involves three key caches:
A “hot” key cache that takes up 20% of the space allocated for all key caches. Use this for tables that are heavily used for searches but that are not updated.
A “cold” key cache that takes up 20% of the space allocated for all key caches. Use this cache for medium-sized, intensively modified tables, such as temporary tables.
A “warm” key cache that takes up 60% of the key cache space. Employ this as the default key cache, to be used by default for all other tables.
One reason the use of three key caches is beneficial is that access to one key cache structure does not block access to the others. Statements that access tables assigned to one cache do not compete with statements that access tables assigned to another cache. Performance gains occur for other reasons as well:
The hot cache is used only for retrieval queries, so its contents are never modified. Consequently, whenever an index block needs to be pulled in from disk, the contents of the cache block chosen for replacement need not be flushed first.
For an index assigned to the hot cache, if there are no queries requiring an index scan, there is a high probability that the index blocks corresponding to nonleaf nodes of the index B-tree remain in the cache.
An update operation most frequently executed for temporary tables is performed much faster when the updated node is in the cache and need not be read in from disk first. If the size of the indexes of the temporary tables are comparable with the size of cold key cache, the probability is very high that the updated node is in the cache.
The CACHE INDEX statement sets
up an association between a table and a key cache, but the
association is lost each time the server restarts. If you want
the association to take effect each time the server starts,
one way to accomplish this is to use an option file: Include
variable settings that configure your key caches, and an
init-file option that names a file
containing CACHE INDEX
statements to be executed. For example:
key_buffer_size = 4G hot_cache.key_buffer_size = 2G cold_cache.key_buffer_size = 2G init_file=/path/to/data-directory/mysqld_init.sql
The statements in mysqld_init.sql are
executed each time the server starts. The file should contain
one SQL statement per line. The following example assigns
several tables each to hot_cache and
cold_cache:
CACHE INDEX db1.t1, db1.t2, db2.t3 IN hot_cache CACHE INDEX db1.t4, db2.t5, db2.t6 IN cold_cache
By default, the key cache management system uses a simple LRU strategy for choosing key cache blocks to be evicted, but it also supports a more sophisticated method called the midpoint insertion strategy.
When using the midpoint insertion strategy, the LRU chain is
divided into two parts: a hot sublist and a warm sublist. The
division point between two parts is not fixed, but the key
cache management system takes care that the warm part is not
“too short,” always containing at least
key_cache_division_limit
percent of the key cache blocks.
key_cache_division_limit is a
component of structured key cache variables, so its value is a
parameter that can be set per cache.
When an index block is read from a table into the key cache, it is placed at the end of the warm sublist. After a certain number of hits (accesses of the block), it is promoted to the hot sublist. At present, the number of hits required to promote a block (3) is the same for all index blocks.
A block promoted into the hot sublist is placed at the end of
the list. The block then circulates within this sublist. If
the block stays at the beginning of the sublist for a long
enough time, it is demoted to the warm sublist. This time is
determined by the value of the
key_cache_age_threshold
component of the key cache.
The threshold value prescribes that, for a key cache
containing N blocks, the block at
the beginning of the hot sublist not accessed within the last
hits is to be moved to
the beginning of the warm sublist. It then becomes the first
candidate for eviction, because blocks for replacement always
are taken from the beginning of the warm sublist.
N *
key_cache_age_threshold / 100
The midpoint insertion strategy enables you to keep
more-valued blocks always in the cache. If you prefer to use
the plain LRU strategy, leave the
key_cache_division_limit
value set to its default of 100.
The midpoint insertion strategy helps to improve performance
when execution of a query that requires an index scan
effectively pushes out of the cache all the index blocks
corresponding to valuable high-level B-tree nodes. To avoid
this, you must use a midpoint insertion strategy with the
key_cache_division_limit set
to much less than 100. Then valuable frequently hit nodes are
preserved in the hot sublist during an index scan operation as
well.
If there are enough blocks in a key cache to hold blocks of an entire index, or at least the blocks corresponding to its nonleaf nodes, it makes sense to preload the key cache with index blocks before starting to use it. Preloading enables you to put the table index blocks into a key cache buffer in the most efficient way: by reading the index blocks from disk sequentially.
Without preloading, the blocks are still placed into the key cache as needed by queries. Although the blocks will stay in the cache, because there are enough buffers for all of them, they are fetched from disk in random order, and not sequentially.
To preload an index into a cache, use the
LOAD INDEX INTO
CACHE statement. For example, the following
statement preloads nodes (index blocks) of indexes of the
tables t1 and t2:
mysql> LOAD INDEX INTO CACHE t1, t2 IGNORE LEAVES;
+---------+--------------+----------+----------+
| Table | Op | Msg_type | Msg_text |
+---------+--------------+----------+----------+
| test.t1 | preload_keys | status | OK |
| test.t2 | preload_keys | status | OK |
+---------+--------------+----------+----------+
The IGNORE LEAVES modifier causes only
blocks for the nonleaf nodes of the index to be preloaded.
Thus, the statement shown preloads all index blocks from
t1, but only blocks for the nonleaf nodes
from t2.
If an index has been assigned to a key cache using a
CACHE INDEX statement,
preloading places index blocks into that cache. Otherwise, the
index is loaded into the default key cache.
It is possible to specify the size of the block buffers for an
individual key cache using the
key_cache_block_size
variable. This permits tuning of the performance of I/O
operations for index files.
The best performance for I/O operations is achieved when the size of read buffers is equal to the size of the native operating system I/O buffers. But setting the size of key nodes equal to the size of the I/O buffer does not always ensure the best overall performance. When reading the big leaf nodes, the server pulls in a lot of unnecessary data, effectively preventing reading other leaf nodes.
To control the size of blocks in the .MYI
index file of MyISAM tables, use the
--myisam-block-size option at
server startup.
A key cache can be restructured at any time by updating its parameter values. For example:
mysql> SET GLOBAL cold_cache.key_buffer_size=4*1024*1024;
If you assign to either the
key_buffer_size or
key_cache_block_size key
cache component a value that differs from the component's
current value, the server destroys the cache's old structure
and creates a new one based on the new values. If the cache
contains any dirty blocks, the server saves them to disk
before destroying and re-creating the cache. Restructuring
does not occur if you change other key cache parameters.
When restructuring a key cache, the server first flushes the contents of any dirty buffers to disk. After that, the cache contents become unavailable. However, restructuring does not block queries that need to use indexes assigned to the cache. Instead, the server directly accesses the table indexes using native file system caching. File system caching is not as efficient as using a key cache, so although queries execute, a slowdown can be anticipated. After the cache has been restructured, it becomes available again for caching indexes assigned to it, and the use of file system caching for the indexes ceases.
InnoDB maintains a buffer pool for
caching data and indexes in memory.
InnoDB manages the pool as a list,
using a least recently used (LRU) algorithm incorporating a
midpoint insertion strategy. When room is needed to add a new
block to the pool, InnoDB evicts
the least recently used block and adds the new block to the
middle of the list. The midpoint insertion strategy in effect
causes the list to be treated as two sublists:
At the head, a sublist of “new” (or “young”) blocks that have been recently used.
At the tail, a sublist of “old” blocks that are less recently used.
As a result of the algorithm, the new sublist contains blocks that are heavily used by queries. The old sublist contains less-used blocks, and candidates for eviction are taken from this sublist.
The LRU algorithm operates as follows by default:
3/8 of the buffer pool is devoted to the old sublist.
The midpoint of the list is the boundary where the tail of the new sublist meets the head of the old sublist.
When InnoDB reads a block into
the buffer pool, it initially inserts it at the midpoint
(the head of the old sublist). A block can be read in as a
result of two types of read requests: Because it is required
(for example, to satisfy query execution), or as part of
read-ahead performed in anticipation that it will be
required.
The first access to a block in the old sublist makes it “young”, causing it to move to the head of the buffer pool (the head of the new sublist). If the block was read in because it was required, the first access occurs immediately and the block is made young. If the block was read in due to read-ahead, the first access does not occur immediately (and might not occur at all before the block is evicted).
As long as no accesses occur for a block in the pool, it “ages” by moving toward the tail of the list. Blocks in both the new and old sublists age as other blocks are made new. Blocks in the old sublist also age as blocks are inserted at the midpoint. Eventually, a block that remains unused for long enough reaches the tail of the old sublist and is evicted.
In the default operation of the buffer pool, a block when read in is loaded at the midpoint and then moved immediately to the head of the new sublist as soon as an access occurs. In the case of a table scan (such as performed for a mysqldump operation), each block read by the scan ends up moving to the head of the new sublist because multiple rows are accessed from each block. This occurs even for a one-time scan, where the blocks are not otherwise used by other queries. Blocks may also be loaded by the read-ahead background thread and then moved to the head of the new sublist by a single access. These effects can be disadvantageous because they push blocks that are in heavy use by other queries out of the new sublist to the old sublist where they become subject to eviction.
InnoDB has several system variables
that control the size of the buffer pool or enable LRU algorithm
tuning:
Specifies the size of the buffer pool. If your buffer pool
is small and you have sufficient memory, making the pool
larger can improve performance by reducing the amount of
disk I/O needed as queries access
InnoDB tables.
Specifies the approximate percentage of the buffer pool that
InnoDB uses for the old block
sublist. The range of values is 5 to 95. The default value
is 37 (that is, 3/8 of the pool).
Specifies how long in milliseconds (ms) a block inserted into the old sublist must stay there after its first access before it can be moved to the new sublist. The default value is 0: A block inserted into the old sublist moves immediately to the new sublist the first time it is accessed, no matter how soon after insertion the access occurs. If the value is greater than 0, blocks remain in the old sublist until an access occurs at least that many ms after the first access. For example, a value of 1000 causes blocks to stay in the old sublist for 1 second after the first access before they become eligible to move to the new sublist.
innodb_old_blocks_pct and
innodb_old_blocks_time are
available as of MySQL 5.1.41, but only for InnoDB
Plugin, not the built-in version of
InnoDB.
By setting
innodb_old_blocks_time greater
than 0, you can prevent one-time table scans from flooding the
new sublist with blocks used only for the scan. Rows in a block
read in for a scan are accessed rapidly many times in
succession, but the block is unused after that. If
innodb_old_blocks_time is set
to a value greater than the block scan time, the block is not
moved to the new sublist during the table scan. Instead, it
remains in the old sublist and ages to the tail of the list to
be evicted quickly. This way, blocks used only for a one-time
scan do not act to the detriment of heavily used blocks in the
new sublist.
innodb_old_blocks_time can be
set at runtime, so you can change it temporarily while
performing operations such as table scans and dumps to prevent
them from flooding the new sublist:
SET GLOBAL innodb_old_blocks_time = 1000;
... perform queries that scan tables ...
SET GLOBAL innodb_old_blocks_time = 0;
This strategy does not apply if your intent is to fill the
buffer pool with a table's content. For example, you might
perform a table or index scan at server startup or during
benchmarking or testing specifically to “warm up”
the buffer pool. In this case, leaving
innodb_old_blocks_time set to 0
accomplishes the goal of loading the scanned blocks into the new
sublist.
The output from the InnoDB Standard Monitor contains several new
fields in the BUFFER POOL AND MEMORY section
that pertain to operation of the buffer pool LRU algorithm:
Old database pages: The number of pages
in the old sublist of the buffer pool.
Pages made young, not young: The number
of old pages that were moved to the head of the buffer pool
(the new sublist), and the number of pages that have
remained in the old sublist without being made new.
youngs/s non-youngs/s: The number of
accesses to old pages that have resulted in making them
young or not. This metric differs from that of the previous
item in two ways. First, it relates only to old pages.
Second, it is based on number of accesses to pages and not
the number of pages. (There can be multiple accesses to a
given page, all of which are counted.)
young-making rate: Hits that cause blocks
to move to the head of the buffer pool.
not: Hits that do not cause blocks to
move to the head of the buffer pool (due to the delay not
being met).
The young-making rate and
not rate will not normally add up to the
overall buffer pool hit rate. Hits for blocks in the old sublist
cause them to move to the new sublist, but hits to blocks in the
new sublist cause them to move to the head of the list only if
they are a certain distance from the head.
The preceding information from the Monitor can help you make LRU tuning decisions:
If you see very low youngs/s values when
you do not have large scans going on, that indicates that
you might need to either reduce the delay time, or increase
the percentage of the buffer pool used for the old sublist.
Increasing the percentage makes the old sublist larger, so
blocks in that sublist take longer to move to the tail and
be evicted. This increases the likelihood that they will be
accessed again and be made young.
If you do not see a lot of non-youngs/s
when you are doing large table scans (and lots of
youngs/s), you will want to tune your
delay value to be larger.
For more information about InnoDB Monitors, see
Section 13.6.13.2, “SHOW ENGINE INNODB
STATUS and the InnoDB Monitors”.
The MyISAM storage engine also uses an LRU
algorithm, to manage its key cache. See
Section 7.6.1, “The MyISAM Key Cache”.
The query cache stores the text of a
SELECT statement together with
the corresponding result that was sent to the client. If an
identical statement is received later, the server retrieves the
results from the query cache rather than parsing and executing
the statement again. The query cache is shared among sessions,
so a result set generated by one client can be sent in response
to the same query issued by another client.
The query cache can be useful in an environment where you have tables that do not change very often and for which the server receives many identical queries. This is a typical situation for many Web servers that generate many dynamic pages based on database content.
The query cache does not return stale data. When tables are modified, any relevant entries in the query cache are flushed.
The query cache does not work in an environment where you have
multiple mysqld servers updating the same
MyISAM tables.
As of MySQL 5.1.17, the query cache is used for prepared statements under the conditions described in Section 7.6.3.1, “How the Query Cache Operates”. Before 5.1.17, the query cache is not used for prepared statements.
Some performance data for the query cache follows. These results were generated by running the MySQL benchmark suite on a Linux Alpha 2×500MHz system with 2GB RAM and a 64MB query cache.
If all the queries you are performing are simple (such as selecting a row from a table with one row), but still differ so that the queries cannot be cached, the overhead for having the query cache active is 13%. This could be regarded as the worst case scenario. In real life, queries tend to be much more complicated, so the overhead normally is significantly lower.
Searches for a single row in a single-row table are 238% faster with the query cache than without it. This can be regarded as close to the minimum speedup to be expected for a query that is cached.
To disable the query cache at server startup, set the
query_cache_size system
variable to 0. By disabling the query cache code, there is no
noticeable overhead. If you build MySQL from source, query cache
capabilities can be excluded from the server entirely by
invoking configure with the
--without-query-cache option.
The query cache offers the potential for substantial performance improvement, but you should not assume that it will do so under all circumstances. With some query cache configurations or server workloads, you might actually see a performance decrease:
Be cautious about sizing the query cache excessively large, which increases the overhead required to maintain the cache, possibly beyond the benefit of enabling it. Sizes in tens of megabytes are usually beneficial. Sizes in the hundreds of megabytes might not be.
Server workload has a significant effect on query cache
efficiency. A query mix consisting almost entirely of a
fixed set of SELECT
statements is much more likely to benefit from enabling the
cache than a mix in which frequent
INSERT statements cause
continual invalidation of results in the cache. In some
cases, a workaround is to use the
SQL_NO_CACHE option to prevent results
from even entering the cache for
SELECT statements that use
frequently modified tables. (See
Section 7.6.3.2, “Query Cache SELECT Options”.)
To verify that enabling the query cache is beneficial, test the operation of your MySQL server with the cache enabled and disabled. Then retest periodically because query cache efficiency may change as server workload changes.
This section describes how the query cache works when it is operational. Section 7.6.3.3, “Query Cache Configuration”, describes how to control whether it is operational.
Incoming queries are compared to those in the query cache before parsing, so the following two queries are regarded as different by the query cache:
SELECT * FROMtbl_nameSelect * fromtbl_name
Queries must be exactly the same (byte for byte) to be seen as identical. In addition, query strings that are identical may be treated as different for other reasons. Queries that use different databases, different protocol versions, or different default character sets are considered different queries and are cached separately.
The cache is not used for queries of the following types:
Queries that are a subquery of an outer query
Queries executed within the body of a stored function, trigger, or event
Before a query result is fetched from the query cache, MySQL
checks whether the user has
SELECT privilege for all
databases and tables involved. If this is not the case, the
cached result is not used.
If a query result is returned from query cache, the server
increments the Qcache_hits
status variable, not Com_select. See
Section 7.6.3.4, “Query Cache Status and Maintenance”.
If a table changes, all cached queries that use the table
become invalid and are removed from the cache. This includes
queries that use MERGE tables that map to
the changed table. A table can be changed by many types of
statements, such as INSERT,
UPDATE,
DELETE,
TRUNCATE TABLE,
ALTER TABLE,
DROP TABLE, or
DROP DATABASE.
The query cache also works within transactions when using
InnoDB tables.
In MySQL 5.1, the result from a
SELECT query on a view is
cached.
The query cache works for SELECT SQL_CALC_FOUND_ROWS
... queries and stores a value that is returned by a
following SELECT FOUND_ROWS() query.
FOUND_ROWS() returns the
correct value even if the preceding query was fetched from the
cache because the number of found rows is also stored in the
cache. The SELECT FOUND_ROWS() query itself
cannot be cached.
Before MySQL 5.1.17, prepared statements do not use the query cache. Beginning with 5.1.17, prepared statements use the query cache under certain conditions, which differ depending on the preparation method:
Statements that are issued using the binary protocol using
mysql_stmt_prepare() and
mysql_stmt_execute(). See
Section 21.9.4, “C API Prepared Statements”.
For a prepared statement executed using the binary
protocol, comparison with statements in the query cache is
based on the text of the statement after expansion of
? parameter markers. The statement is
compared only with other cached statements that were
executed using the binary protocol. That is, for query
cache purposes, statements issued using the binary
protocol are distinct from statements issued using the
text protocol.
Statements that are issued using the text (nonbinary)
protocol using PREPARE and
EXECUTE. See
Section 12.6, “SQL Syntax for Prepared Statements”. These
are denoted SQL PS statements here.
Before MySQL 5.1.21, for a prepared statement executed
using PREPARE and
EXECUTE, it is not cached
if it contains any ? parameter markers.
In that case, the statement after parameter expansion
contains references to user variables, which prevents
caching, even for nonprepared statements. If the statement
contains no parameter markers, the statement is compared
with statements in the query cache that were executed
using the text protocol (that is, it is compared with
other SQL PS statements and nonprepared statements). As of
MySQL 5.1.21, this limitation is lifted and prepared
statements that contain parameter markers can be cached
because expansion directly substitutes the user variable
values.
A query cannot be cached if it contains any of the functions shown in the following table.
A query also is not cached under these conditions:
It refers to user-defined functions (UDFs) or stored functions.
It refers to user variables or local stored program variables.
It refers to tables in the mysql or
INFORMATION_SCHEMA system database.
It is of any of the following forms:
SELECT ... LOCK IN SHARE MODE SELECT ... FOR UPDATE SELECT ... INTO OUTFILE ... SELECT ... INTO DUMPFILE ... SELECT * FROM ... WHERE autoincrement_col IS NULL
The last form is not cached because it is used as the ODBC workaround for obtaining the last insert ID value. See the MyODBC section of Chapter 21, Connectors and APIs.
Statements within transactions that use
SERIALIZABLE isolation
level also cannot be cached because they use LOCK
IN SHARE MODE locking.
It uses TEMPORARY tables.
It does not use any tables.
It generates warnings.
The user has a column-level privilege for any of the involved tables.
Two query cache-related options may be specified in
SELECT statements:
The query result is cached if it is cacheable and the
value of the
query_cache_type system
variable is ON or
DEMAND.
SQL_NO_CACHE
The query result is not cached.
Examples:
SELECT SQL_CACHE id, name FROM customer; SELECT SQL_NO_CACHE id, name FROM customer;
The have_query_cache server
system variable indicates whether the query cache is
available:
mysql> SHOW VARIABLES LIKE 'have_query_cache';
+------------------+-------+
| Variable_name | Value |
+------------------+-------+
| have_query_cache | YES |
+------------------+-------+
When using a standard MySQL binary, this value is always
YES, even if query caching is disabled.
Several other system variables control query cache operation.
These can be set in an option file or on the command line when
starting mysqld. The query cache system
variables all have names that begin with
query_cache_. They are described briefly in
Section 5.1.4, “Server System Variables”, with additional
configuration information given here.
To set the size of the query cache, set the
query_cache_size system
variable. Setting it to 0 disables the query cache. The
default size is 0, so the query cache is disabled by default.
When using the Windows Configuration Wizard to install or
configure MySQL, the default value for
query_cache_size will be
configured automatically for you based on the different
configuration types available. When using the Windows
Configuration Wizard, the query cache may be enabled (that
is, set to a nonzero value) due to the selected
configuration. The query cache is also controlled by the
setting of the
query_cache_type variable.
You should check the values of these variables as set in
your my.ini file after configuration
has taken place.
When you set query_cache_size
to a nonzero value, keep in mind that the query cache needs a
minimum size of about 40KB to allocate its structures. (The
exact size depends on system architecture.) If you set the
value too small, you'll get a warning, as in this example:
mysql>SET GLOBAL query_cache_size = 40000;Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>SHOW WARNINGS\G*************************** 1. row *************************** Level: Warning Code: 1282 Message: Query cache failed to set size 39936; new query cache size is 0 mysql>SET GLOBAL query_cache_size = 41984;Query OK, 0 rows affected (0.00 sec) mysql>SHOW VARIABLES LIKE 'query_cache_size';+------------------+-------+ | Variable_name | Value | +------------------+-------+ | query_cache_size | 41984 | +------------------+-------+
For the query cache to actually be able to hold any query results, its size must be set larger:
mysql>SET GLOBAL query_cache_size = 1000000;Query OK, 0 rows affected (0.04 sec) mysql>SHOW VARIABLES LIKE 'query_cache_size';+------------------+--------+ | Variable_name | Value | +------------------+--------+ | query_cache_size | 999424 | +------------------+--------+ 1 row in set (0.00 sec)
The query_cache_size value is
aligned to the nearest 1024 byte block. The value reported may
therefore be different from the value that you assign.
If the query cache size is greater than 0, the
query_cache_type variable
influences how it works. This variable can be set to the
following values:
A value of 0 or OFF
prevents caching or retrieval of cached results.
A value of 1 or ON
enables caching except of those statements that begin with
SELECT SQL_NO_CACHE.
A value of 2 or
DEMAND causes caching of only those
statements that begin with SELECT
SQL_CACHE.
Setting the GLOBAL
query_cache_type value
determines query cache behavior for all clients that connect
after the change is made. Individual clients can control cache
behavior for their own connection by setting the
SESSION
query_cache_type value. For
example, a client can disable use of the query cache for its
own queries like this:
mysql> SET SESSION query_cache_type = OFF;
If you set query_cache_type
at server startup (rather than at runtime with a
SET
statement), only the numeric values are permitted.
To control the maximum size of individual query results that
can be cached, set the
query_cache_limit system
variable. The default value is 1MB.
You can set the maximum size that can be specified for the
query cache at run time with the
SET
statement by using the
--maximum-query_cache_size=
option on the command line or in the configuration file.
32M
When a query is to be cached, its result (the data sent to the
client) is stored in the query cache during result retrieval.
Therefore the data usually is not handled in one big chunk.
The query cache allocates blocks for storing this data on
demand, so when one block is filled, a new block is allocated.
Because memory allocation operation is costly (timewise), the
query cache allocates blocks with a minimum size given by the
query_cache_min_res_unit
system variable. When a query is executed, the last result
block is trimmed to the actual data size so that unused memory
is freed. Depending on the types of queries your server
executes, you might find it helpful to tune the value of
query_cache_min_res_unit:
The default value of
query_cache_min_res_unit
is 4KB. This should be adequate for most cases.
If you have a lot of queries with small results, the
default block size may lead to memory fragmentation, as
indicated by a large number of free blocks. Fragmentation
can force the query cache to prune (delete) queries from
the cache due to lack of memory. In this case, you should
decrease the value of
query_cache_min_res_unit.
The number of free blocks and queries removed due to
pruning are given by the values of the
Qcache_free_blocks and
Qcache_lowmem_prunes
status variables.
If most of your queries have large results (check the
Qcache_total_blocks and
Qcache_queries_in_cache
status variables), you can increase performance by
increasing
query_cache_min_res_unit.
However, be careful to not make it too large (see the
previous item).
To check whether the query cache is present in your MySQL server, use the following statement:
mysql> SHOW VARIABLES LIKE 'have_query_cache';
+------------------+-------+
| Variable_name | Value |
+------------------+-------+
| have_query_cache | YES |
+------------------+-------+
You can defragment the query cache to better utilize its
memory with the FLUSH
QUERY CACHE statement. The statement does not remove
any queries from the cache.
The RESET QUERY CACHE statement removes all
query results from the query cache. The
FLUSH TABLES
statement also does this.
To monitor query cache performance, use
SHOW STATUS to view the cache
status variables:
mysql> SHOW STATUS LIKE 'Qcache%';
+-------------------------+--------+
| Variable_name | Value |
+-------------------------+--------+
| Qcache_free_blocks | 36 |
| Qcache_free_memory | 138488 |
| Qcache_hits | 79570 |
| Qcache_inserts | 27087 |
| Qcache_lowmem_prunes | 3114 |
| Qcache_not_cached | 22989 |
| Qcache_queries_in_cache | 415 |
| Qcache_total_blocks | 912 |
+-------------------------+--------+
Descriptions of each of these variables are given in Section 5.1.6, “Server Status Variables”. Some uses for them are described here.
The total number of SELECT
queries is given by this formula:
Com_select + Qcache_hits + queries with errors found by parser
The Com_select value is given by this
formula:
Qcache_inserts + Qcache_not_cached + queries with errors found during the column-privileges check
The query cache uses variable-length blocks, so
Qcache_total_blocks and
Qcache_free_blocks may
indicate query cache memory fragmentation. After
FLUSH QUERY
CACHE, only a single free block remains.
Every cached query requires a minimum of two blocks (one for the query text and one or more for the query results). Also, every table that is used by a query requires one block. However, if two or more queries use the same table, only one table block needs to be allocated.
The information provided by the
Qcache_lowmem_prunes status
variable can help you tune the query cache size. It counts the
number of queries that have been removed from the cache to
free up memory for caching new queries. The query cache uses a
least recently used (LRU) strategy to decide which queries to
remove from the cache. Tuning information is given in
Section 7.6.3.3, “Query Cache Configuration”.
MySQL manages contention for table contents using locking:
Internal locking is performed within the MySQL server itself to manage contention for table contents by multiple threads. This type of locking is internal because it is performed entirely by the server and involves no other programs. See Section 7.7.1, “Internal Locking Methods”.
External locking occurs when the server and other programs lock table files to coordinate among themselves which program can access the tables at which time. See Section 7.7.4, “External Locking”.
This section discusses internal locking; that is, locking performed within the MySQL server itself to manage contention for table contents by multiple sessions. This type of locking is internal because it is performed entirely by the server and involves no other programs. External locking occurs when the server and other programs lock table files to coordinate among themselves which program can access the tables at which time. See Section 7.7.4, “External Locking”.
MySQL uses row-level locking for InnoDB
tables, and table-level locking for MyISAM,
MEMORY, and MERGE tables.
Which lock type works better for your application depends on the application and its workload, especially whether the data is modified frequently and how many concurrent sessions need to read or write the same tables. Different parts of an application may require different lock types.
To decide whether you want to use a storage engine with
row-level locking, look at what your application does and what
mix of select and update statements it uses. For example, the
InnoDB storage engine is targeted towards a
wide variety of application workloads, especially those with
heavy write activity or high concurrent usage. The
MyISAM storage engine is targeted towards Web
applications that perform many selects, relatively few deletes,
updates based mainly on key values, and inserts into a few
specific tables.
Table locking in MySQL is deadlock-free for storage engines that use table-level locking. Deadlock avoidance is managed by always requesting all needed locks at once at the beginning of a query and always locking the tables in the same order.
MySQL grants table write locks as follows:
If there are no locks on the table, put a write lock on it.
Otherwise, put the lock request in the write lock queue.
MySQL grants table read locks as follows:
If there are no write locks on the table, put a read lock on it.
Otherwise, put the lock request in the read lock queue.
Table updates are given higher priority than table retrievals.
Therefore, when a lock is released, the lock is made available
to the requests in the write lock queue and then to the requests
in the read lock queue. This ensures that updates to a table are
not “starved” even if there is heavy
SELECT activity for the table.
However, if you have many updates for a table,
SELECT statements wait until
there are no more updates.
For information on altering the priority of reads and writes, see Section 7.7.2, “Table Locking Issues”.
You can analyze the table lock contention on your system by
checking the
Table_locks_immediate and
Table_locks_waited status
variables, which indicate the number of times that requests for
table locks could be granted immediately and the number that had
to wait, respectively:
mysql> SHOW STATUS LIKE 'Table%';
+-----------------------+---------+
| Variable_name | Value |
+-----------------------+---------+
| Table_locks_immediate | 1151552 |
| Table_locks_waited | 15324 |
+-----------------------+---------+
The MyISAM storage engine supports concurrent
inserts to reduce contention between readers and writers for a
given table: If a MyISAM table has no free
blocks in the middle of the data file, rows are always inserted
at the end of the data file. In this case, you can freely mix
concurrent INSERT and
SELECT statements for a
MyISAM table without locks. That is, you can
insert rows into a MyISAM table at the same
time other clients are reading from it. Holes can result from
rows having been deleted from or updated in the middle of the
table. If there are holes, concurrent inserts are disabled but
are enabled again automatically when all holes have been filled
with new data. This behavior is altered by the
concurrent_insert system
variable. See Section 7.7.3, “Concurrent Inserts”.
If you acquire a table lock explicitly with
LOCK TABLES, you can request a
READ LOCAL lock rather than a
READ lock to enable other sessions to perform
concurrent inserts while you have the table locked.
To perform many INSERT and
SELECT operations on a table
real_table when concurrent inserts are not
possible, you can insert rows into a temporary table
temp_table and update the real table with the
rows from the temporary table periodically. This can be done
with the following code:
mysql>LOCK TABLES real_table WRITE, temp_table WRITE;mysql>INSERT INTO real_table SELECT * FROM temp_table;mysql>DELETE FROM temp_table;mysql>UNLOCK TABLES;
InnoDB uses row locks. Deadlocks are possible
for InnoDB because it automatically acquires
locks during the processing of SQL statements, not at the start
of the transaction.
Advantages of row-level locking:
Fewer lock conflicts when different sessions access different rows
Fewer changes for rollbacks
Possible to lock a single row for a long time
Disadvantages of row-level locking:
Requires more memory than table-level locks
Slower than table-level locks when used on a large part of the table because you must acquire many more locks
Slower than other locks if you often do GROUP
BY operations on a large part of the data or if
you must scan the entire table frequently
Generally, table locks are superior to row-level locks in the following cases:
Most statements for the table are reads
Statements for the table are a mix of reads and writes, where writes are updates or deletes for a single row that can be fetched with one key read:
UPDATEtbl_nameSETcolumn=valueWHEREunique_key_col=key_value; DELETE FROMtbl_nameWHEREunique_key_col=key_value;
SELECT combined with
concurrent INSERT statements,
and very few UPDATE or
DELETE statements
Many scans or GROUP BY operations on the
entire table without any writers
With higher-level locks, you can more easily tune applications by supporting locks of different types, because the lock overhead is less than for row-level locks.
Options other than row-level locking:
Versioning (such as that used in MySQL for concurrent inserts) where it is possible to have one writer at the same time as many readers. This means that the database or table supports different views for the data depending on when access begins. Other common terms for this are “time travel,” “copy on write,” or “copy on demand.”
Copy on demand is in many cases superior to row-level locking. However, in the worst case, it can use much more memory than using normal locks.
Instead of using row-level locks, you can employ
application-level locks, such as those provided by
GET_LOCK() and
RELEASE_LOCK() in MySQL.
These are advisory locks, so they work only with
applications that cooperate with each other. See
Section 11.15, “Miscellaneous Functions”.
To achieve a very high lock speed, MySQL uses table locking
(instead of page, row, or column locking) for all storage
engines except InnoDB and
NDBCLUSTER.
For InnoDB tables, MySQL uses table locking
only if you explicitly lock the table with
LOCK TABLES. For this storage
engine, avoid using LOCK TABLES
at all, because InnoDB uses automatic
row-level locking to ensure transaction isolation.
For large tables, table locking is often better than row locking, but there are some disadvantages:
Table locking enables many sessions to read from a table at the same time, but if a session wants to write to a table, it must first get exclusive access. During the update, all other sessions that want to access this particular table must wait until the update is done.
Table locking causes problems in cases such as when a session is waiting because the disk is full and free space needs to become available before the session can proceed. In this case, all sessions that want to access the problem table are also put in a waiting state until more disk space is made available.
Table locking is also disadvantageous under the following scenario:
A session issues a SELECT
that takes a long time to run.
Another session then issues an
UPDATE on the same table.
This session waits until the
SELECT is finished.
Another session issues another
SELECT statement on the same
table. Because UPDATE has
higher priority than SELECT,
this SELECT waits for the
UPDATE to finish,
after waiting for the first
SELECT to finish.
The following items describe some ways to avoid or reduce contention caused by table locking:
Try to get the SELECT
statements to run faster so that they lock tables for a
shorter time. You might have to create some summary tables
to do this.
Start mysqld with
--low-priority-updates. For
storage engines that use only table-level locking (such as
MyISAM, MEMORY, and
MERGE), this gives all statements that
update (modify) a table lower priority than
SELECT statements. In this
case, the second SELECT
statement in the preceding scenario would execute before the
UPDATE statement, and would
not need to wait for the first
SELECT to finish.
To specify that all updates issued in a specific connection
should be done with low priority, set the
low_priority_updates server
system variable equal to 1.
To give a specific INSERT,
UPDATE, or
DELETE statement lower
priority, use the LOW_PRIORITY attribute.
To give a specific SELECT
statement higher priority, use the
HIGH_PRIORITY attribute. See
Section 12.2.8, “SELECT Syntax”.
Start mysqld with a low value for the
max_write_lock_count system
variable to force MySQL to temporarily elevate the priority
of all SELECT statements that
are waiting for a table after a specific number of inserts
to the table occur. This permits READ
locks after a certain number of WRITE
locks.
If you have problems with
INSERT combined with
SELECT, consider switching to
MyISAM tables, which support concurrent
SELECT and
INSERT statements. (See
Section 7.7.3, “Concurrent Inserts”.)
If you mix inserts and deletes on the same table,
INSERT DELAYED may be of
great help. See Section 12.2.5.2, “INSERT DELAYED Syntax”.
If you have problems with mixed
SELECT and
DELETE statements, the
LIMIT option to
DELETE may help. See
Section 12.2.2, “DELETE Syntax”.
Using SQL_BUFFER_RESULT with
SELECT statements can help to
make the duration of table locks shorter. See
Section 12.2.8, “SELECT Syntax”.
You could change the locking code in
mysys/thr_lock.c to use a single queue.
In this case, write locks and read locks would have the same
priority, which might help some applications.
Here are some tips concerning table locks in MySQL:
Concurrent users are not a problem if you do not mix updates with selects that need to examine many rows in the same table.
You can use LOCK TABLES to
increase speed, because many updates within a single lock is
much faster than updating without locks. Splitting table
contents into separate tables may also help.
If you encounter speed problems with table locks in MySQL,
you may be able to improve performance by converting some of
your tables to InnoDB. See
Section 13.6, “The InnoDB Storage Engine”.
The MyISAM storage engine supports concurrent
inserts to reduce contention between readers and writers for a
given table: If a MyISAM table has no holes
in the data file (deleted rows in the middle), an
INSERT statement can be executed
to add rows to the end of the table at the same time that
SELECT statements are reading
rows from the table. If there are multiple
INSERT statements, they are
queued and performed in sequence, concurrently with the
SELECT statements. The results of
a concurrent INSERT may not be
visible immediately.
The concurrent_insert system
variable can be set to modify the concurrent-insert processing.
By default, the variable is set to 1 and concurrent inserts are
handled as just described. If
concurrent_insert is set to 0,
concurrent inserts are disabled. If the variable is set to 2,
concurrent inserts at the end of the table are permitted even
for tables that have deleted rows. See also the description of
the
concurrent_insert
system variable.
Under circumstances where concurrent inserts can be used, there
is seldom any need to use the DELAYED
modifier for INSERT statements.
See Section 12.2.5.2, “INSERT DELAYED Syntax”.
If you are using the binary log, concurrent inserts are
converted to normal inserts for CREATE ...
SELECT or
INSERT ...
SELECT statements. This is done to ensure that you can
re-create an exact copy of your tables by applying the log
during a backup operation. See Section 5.2.4, “The Binary Log”. In
addition, for those statements a read lock is placed on the
selected-from table such that inserts into that table are
blocked. The effect is that concurrent inserts for that table
must wait as well.
With LOAD DATA
INFILE, if you specify CONCURRENT
with a MyISAM table that satisfies the
condition for concurrent inserts (that is, it contains no free
blocks in the middle), other sessions can retrieve data from the
table while LOAD DATA is
executing. Use of the CONCURRENT option
affects the performance of LOAD
DATA a bit, even if no other session is using the
table at the same time.
If you specify HIGH_PRIORITY, it overrides
the effect of the
--low-priority-updates option if
the server was started with that option. It also causes
concurrent inserts not to be used.
For LOCK
TABLE, the difference between READ
LOCAL and READ is that
READ LOCAL permits nonconflicting
INSERT statements (concurrent
inserts) to execute while the lock is held. However, this cannot
be used if you are going to manipulate the database using
processes external to the server while you hold the lock.
External locking is the use of file system locking to manage contention for database tables by multiple processes. External locking is used in situations where a single process such as the MySQL server cannot be assumed to be the only process that requires access to tables. Here are some examples:
If you run multiple servers that use the same database directory (not recommended), each server must have external locking enabled.
If you use myisamchk to perform table
maintenance operations on MyISAM tables,
you must either ensure that the server is not running, or
that the server has external locking enabled so that it
locks table files as necessary to coordinate with
myisamchk for access to the tables. The
same is true for use of myisampack to
pack MyISAM tables.
If the server is run with external locking enabled, you can use myisamchk at any time for read operations such a checking tables. In this case, if the server tries to update a table that myisamchk is using, the server will wait for myisamchk to finish before it continues.
If you use myisamchk for write operations such as repairing or optimizing tables, or if you use myisampack to pack tables, you must always ensure that the mysqld server is not using the table. If you don't stop mysqld, you should at least do a mysqladmin flush-tables before you run myisamchk. Your tables may become corrupted if the server and myisamchk access the tables simultaneously.
With external locking in effect, each process that requires access to a table acquires a file system lock for the table files before proceeding to access the table. If all necessary locks cannot be acquired, the process is blocked from accessing the table until the locks can be obtained (after the process that currently holds the locks releases them).
External locking affects server performance because the server must sometimes wait for other processes before it can access tables.
External locking is unnecessary if you run a single server to access a given data directory (which is the usual case) and if no other programs such as myisamchk need to modify tables while the server is running. If you only read tables with other programs, external locking is not required, although myisamchk might report warnings if the server changes tables while myisamchk is reading them.
With external locking disabled, to use
myisamchk, you must either stop the server
while myisamchk executes or else lock and
flush the tables before running myisamchk.
(See Section 7.9.1, “System Factors and Startup Parameter Tuning”.) To avoid this
requirement, use the CHECK TABLE
and REPAIR TABLE statements to
check and repair MyISAM tables.
For mysqld, external locking is controlled by
the value of the
skip_external_locking system
variable. When this variable is enabled, external locking is
disabled, and vice versa. From MySQL 4.0 on, external locking is
disabled by default.
Use of external locking can be controlled at server startup by
using the --external-locking or
--skip-external-locking option.
If you do use external locking option to enable updates to
MyISAM tables from many MySQL processes, you
must ensure that the following conditions are satisfied:
You should not use the query cache for queries that use tables that are updated by another process.
You should not start the server with the
--delay-key-write=ALL option
or use the DELAY_KEY_WRITE=1 table option
for any shared tables. Otherwise, index corruption can
occur.
The easiest way to satisfy these conditions is to always use
--external-locking together with
--delay-key-write=OFF and
--query-cache-size=0. (This is
not done by default because in many setups it is useful to have
a mixture of the preceding options.)
One of the most basic optimizations is to design your tables to take as little space on the disk as possible. This can result in huge improvements because disk reads are faster, and smaller tables normally require less main memory while their contents are being actively processed during query execution. Indexing also is a lesser resource burden if done on smaller columns.
MySQL supports many different storage engines (table types) and row formats. For each table, you can decide which storage and indexing method to use. Choosing the proper table format for your application may give you a big performance gain. See Chapter 13, Storage Engines.
You can get better performance for a table and minimize storage space by using the techniques listed here:
Use the most efficient (smallest) data types possible. MySQL
has many specialized types that save disk space and memory.
For example, use the smaller integer types if possible to
get smaller tables. MEDIUMINT
is often a better choice than
INT because a
MEDIUMINT column uses 25%
less space.
Declare columns to be NOT NULL if
possible. It makes everything faster and you save one bit
per column. If you really need NULL in
your application, you should definitely use it. Just avoid
having it on all columns by default.
For MyISAM tables, if you do not have any
variable-length columns
(VARCHAR,
TEXT, or
BLOB columns), a fixed-size
row format is used. This is faster but unfortunately may
waste some space. See
Section 13.5.3, “MyISAM Table Storage Formats”. You can hint that
you want to have fixed length rows even if you have
VARCHAR columns with the
CREATE TABLE option
ROW_FORMAT=FIXED.
InnoDB tables use a compact storage
format. In versions of MySQL earlier than 5.0.3,
InnoDB rows contain some redundant
information, such as the number of columns and the length of
each column, even for fixed-size columns. By default, tables
are created in the compact format
(ROW_FORMAT=COMPACT). If you wish to
downgrade to older versions of MySQL, you can request the
old format with ROW_FORMAT=REDUNDANT.
The presence of the compact row format decreases row storage space by about 20% at the cost of increasing CPU use for some operations. If your workload is a typical one that is limited by cache hit rates and disk speed it is likely to be faster. If it is a rare case that is limited by CPU speed, it might be slower.
The compact InnoDB format also changes
how CHAR columns containing
UTF-8 data are stored. With
ROW_FORMAT=REDUNDANT, a UTF-8
CHAR(
occupies 3 × N)N bytes, given
that the maximum length of a UTF-8 encoded character is
three bytes. Many languages can be written primarily using
single-byte UTF-8 characters, so a fixed storage length
often wastes space. With
ROW_FORMAT=COMPACT format,
InnoDB allocates a variable amount of
storage in the range from N to 3
× N bytes for these columns
by stripping trailing spaces if necessary. The minimum
storage length is kept as N bytes
to facilitate in-place updates in typical cases.
The primary index of a table should be as short as possible. This makes identification of each row easy and efficient.
Create only the indexes that you really need. Indexes are good for retrieval but bad when you need to store data quickly. If you access a table mostly by searching on a combination of columns, create an index on them. The first part of the index should be the column most used. If you always use many columns when selecting from the table, the first column in the index should be the one with the most duplicates to obtain better compression of the index.
If it is very likely that a string column has a unique
prefix on the first number of characters, it is better to
index only this prefix, using MySQL's support for creating
an index on the leftmost part of the column (see
Section 12.1.13, “CREATE INDEX Syntax”). Shorter indexes are faster,
not only because they require less disk space, but because
they also give you more hits in the index cache, and thus
fewer disk seeks. See Section 7.9.2, “Tuning Server Parameters”.
In some circumstances, it can be beneficial to split into two a table that is scanned very often. This is especially true if it is a dynamic-format table and it is possible to use a smaller static format table that can be used to find the relevant rows when scanning the table.
When you execute a mysqladmin status command, you should see something like this:
Uptime: 426 Running threads: 1 Questions: 11082 Reloads: 1 Open tables: 12
The Open tables value of 12 can be somewhat
puzzling if you have only six tables.
MySQL is multi-threaded, so there may be many clients issuing
queries for a given table simultaneously. To minimize the
problem with multiple client sessions having different states on
the same table, the table is opened independently by each
concurrent session. This uses additional memory but normally
increases performance. With MyISAM tables,
one extra file descriptor is required for the data file for each
client that has the table open. (By contrast, the index file
descriptor is shared between all sessions.)
table_open_cache was known as
table_cache in MySQL 5.1.2
and earlier.
The table_open_cache,
max_connections, and
max_tmp_tables system variables
affect the maximum number of files the server keeps open. If you
increase one or more of these values, you may run up against a
limit imposed by your operating system on the per-process number
of open file descriptors. Many operating systems permit you to
increase the open-files limit, although the method varies widely
from system to system. Consult your operating system
documentation to determine whether it is possible to increase
the limit and how to do so.
table_open_cache is related to
max_connections. For example,
for 200 concurrent running connections, you should have a table
cache size of at least 200 *
, where
NN is the maximum number of tables per
join in any of the queries which you execute. You must also
reserve some extra file descriptors for temporary tables and
files.
Make sure that your operating system can handle the number of
open file descriptors implied by the
table_open_cache setting. If
table_open_cache is set too
high, MySQL may run out of file descriptors and refuse
connections, fail to perform queries, and be very unreliable.
You also have to take into account that the
MyISAM storage engine needs two file
descriptors for each unique open table. You can increase the
number of file descriptors available to MySQL using the
--open-files-limit startup option
to mysqld. See
Section C.5.2.18, “'File' Not Found and
Similar Errors”.
The cache of open tables is kept at a level of
table_open_cache entries. The
default value is 64; this can be changed with the
--table_open_cache option to
mysqld. Note that MySQL may temporarily open
more tables than this to execute queries.
MySQL closes an unused table and removes it from the table cache under the following circumstances:
When the cache is full and a thread tries to open a table that is not in the cache.
When the cache contains more than
table_open_cache entries
and a table in the cache is no longer being used by any
threads.
When a table flushing operation occurs. This happens when
someone issues a
FLUSH
TABLES statement or executes a mysqladmin
flush-tables or mysqladmin
refresh command.
When the table cache fills up, the server uses the following procedure to locate a cache entry to use:
Tables that are not currently in use are released, beginning with the table least recently used.
If a new table needs to be opened, but the cache is full and no tables can be released, the cache is temporarily extended as necessary. When the cache is in a temporarily extended state and a table goes from a used to unused state, the table is closed and released from the cache.
A MyISAM table is opened for each concurrent
access. This means the table needs to be opened twice if two
threads access the same table or if a thread accesses the table
twice in the same query (for example, by joining the table to
itself). Each concurrent open requires an entry in the table
cache. The first open of any MyISAM table
takes two file descriptors: one for the data file and one for
the index file. Each additional use of the table takes only one
file descriptor for the data file. The index file descriptor is
shared among all threads.
If you are opening a table with the HANDLER
statement, a
dedicated table object is allocated for the thread. This table
object is not shared by other threads and is not closed until
the thread calls tbl_name OPENHANDLER
or the
thread terminates. When this happens, the table is put back in
the table cache (if the cache is not full). See
Section 12.2.4, “tbl_name CLOSEHANDLER Syntax”.
You can determine whether your table cache is too small by
checking the mysqld status variable
Opened_tables, which indicates
the number of table-opening operations since the server started:
mysql> SHOW GLOBAL STATUS LIKE 'Opened_tables';
+---------------+-------+
| Variable_name | Value |
+---------------+-------+
| Opened_tables | 2741 |
+---------------+-------+
If the value is very large or increases rapidly, even when you
have not issued many
FLUSH TABLES
statements, you should increase the table cache size. See
Section 5.1.4, “Server System Variables”, and
Section 5.1.6, “Server Status Variables”.
If you have many MyISAM tables in the same
database directory, open, close, and create operations are slow.
If you execute SELECT statements
on many different tables, there is a little overhead when the
table cache is full, because for every table that has to be
opened, another must be closed. You can reduce this overhead by
increasing the number of entries permitted in the table cache.
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. The server may create a temporary table
initially as an in-memory table, then convert it to an on-disk
table if it becomes too large. Users have no direct control over
when the server creates an internal temporary table or which
storage engine the server uses to manage it.
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:
The SHOW COLUMNS and The
DESCRIBE statements use
BLOB as the type for some columns, thus the
temporary table used for the results is an on-disk table.
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: For
such tables, 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.
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.
We start with system-level factors, because some of these decisions must be made very early to achieve large performance gains. In other cases, a quick look at this section may suffice. However, it is always nice to have a sense of how much can be gained by changing factors that apply at this level.
The operating system to use is very important. To get the best use of multiple-CPU machines, you should use Solaris (because its threads implementation works well) or Linux (because the 2.4 and later kernels have good SMP support). Note that older Linux kernels have a 2GB filesize limit by default. If you have such a kernel and a need for files larger than 2GB, you should get the Large File Support (LFS) patch for the ext2 file system. Other file systems such as ReiserFS and XFS do not have this 2GB limitation.
Before using MySQL in production, we advise you to test it on your intended platform.
Other tips:
If you have enough RAM, you could remove all swap devices. Some operating systems use a swap device in some contexts even if you have free memory.
Avoid external locking. Since MySQL 4.0, the default has
been for external locking to be disabled on all systems. The
--external-locking and
--skip-external-locking
options explicitly enable and disable external locking.
Note that disabling external locking does not affect MySQL's functionality as long as you run only one server. Just remember to take down the server (or lock and flush the relevant tables) before you run myisamchk. On some systems it is mandatory to disable external locking because it does not work, anyway.
The only case in which you cannot disable external locking is when you run multiple MySQL servers (not clients) on the same data, or if you run myisamchk to check (not repair) a table without telling the server to flush and lock the tables first. Note that using multiple MySQL servers to access the same data concurrently is generally not recommended, except when using MySQL Cluster.
The LOCK TABLES and
UNLOCK
TABLES statements use internal locking, so you can
use them even if external locking is disabled.
You can determine the default buffer sizes used by the mysqld server using this command:
shell> mysqld --verbose --help
This command produces a list of all mysqld options and configurable system variables. The output includes the default variable values and looks something like this:
abort-slave-event-count 0 allow-suspicious-udfs FALSE auto-increment-increment 1 auto-increment-offset 1 automatic-sp-privileges TRUE back_log 50 basedir /home/jon/bin/mysql-5.1/ bind-address (No default value) binlog-row-event-max-size 1024 binlog_cache_size 32768 binlog_format (No default value) bulk_insert_buffer_size 8388608 character-set-client-handshake TRUE character-set-filesystem binary character-set-server latin1 character-sets-dir /home/jon/bin/mysql-5.1/share/mysql/charsets/ chroot (No default value) collation-server latin1_swedish_ci completion-type 0 concurrent-insert 1 connect_timeout 10 console FALSE datadir . datetime_format %Y-%m-%d %H:%i:%s date_format %Y-%m-%d default-character-set latin1 default-collation latin1_swedish_ci default-storage-engine MyISAM default-table-type MyISAM default-time-zone (No default value) default_week_format 0 delayed_insert_limit 100 delayed_insert_timeout 300 delayed_queue_size 1000 disconnect-slave-event-count 0 div_precision_increment 4 enable-locking FALSE engine-condition-pushdown TRUE expire_logs_days 0 external-locking FALSE flush_time 0 ft_max_word_len 84 ft_min_word_len 4 ft_query_expansion_limit 20 ft_stopword_file (No default value) gdb FALSE general_log FALSE general_log_file (No default value) group_concat_max_len 1024 help TRUE init-connect (No default value) init-file (No default value) init-slave (No default value) innodb TRUE innodb-adaptive-hash-index TRUE innodb-additional-mem-pool-size 1048576 innodb-autoextend-increment 8 innodb-autoinc-lock-mode 1 innodb-buffer-pool-size 8388608 innodb-checksums TRUE innodb-commit-concurrency 0 innodb-concurrency-tickets 500 innodb-data-file-path (No default value) innodb-data-home-dir (No default value) innodb-doublewrite TRUE innodb-fast-shutdown 1 innodb-file-io-threads 4 innodb-file-per-table FALSE innodb-flush-log-at-trx-commit 1 innodb-flush-method (No default value) innodb-force-recovery 0 innodb-lock-wait-timeout 50 innodb-locks-unsafe-for-binlog FALSE innodb-log-buffer-size 1048576 innodb-log-file-size 5242880 innodb-log-files-in-group 2 innodb-log-group-home-dir (No default value) innodb-max-dirty-pages-pct 90 innodb-max-purge-lag 0 innodb-mirrored-log-groups 1 innodb-open-files 300 innodb-rollback-on-timeout FALSE innodb-stats-on-metadata TRUE innodb-status-file FALSE innodb-support-xa TRUE innodb-sync-spin-loops 20 innodb-table-locks TRUE innodb-thread-concurrency 8 innodb-thread-sleep-delay 10000 interactive_timeout 28800 join_buffer_size 131072 keep_files_on_create FALSE key_buffer_size 8384512 key_cache_age_threshold 300 key_cache_block_size 1024 key_cache_division_limit 100 language /home/jon/bin/mysql-5.1/share/mysql/english/ large-pages FALSE lc-time-names en_US local-infile TRUE log (No default value) log-bin (No default value) log-bin-index (No default value) log-bin-trust-function-creators FALSE log-bin-trust-routine-creators FALSE log-error log-isam myisam.log log-output FILE log-queries-not-using-indexes FALSE log-short-format FALSE log-slave-updates FALSE log-slow-admin-statements FALSE log-slow-slave-statements FALSE log-tc tc.log log-tc-size 24576 log-update (No default value) log-warnings 1 log_slow_queries (No default value) long_query_time 10 low-priority-updates FALSE lower_case_table_names 0 master-connect-retry 60 master-host (No default value) master-info-file master.info master-password (No default value) master-port 3306 master-retry-count 86400 master-ssl FALSE master-ssl-ca (No default value) master-ssl-capath (No default value) master-ssl-cert (No default value) master-ssl-cipher (No default value) master-ssl-key (No default value) master-user test max-binlog-dump-events 0 max_allowed_packet 1048576 max_binlog_cache_size 18446744073709547520 max_binlog_size 1073741824 max_connections 151 max_connect_errors 10 max_delayed_threads 20 max_error_count 64 max_heap_table_size 16777216 max_join_size 18446744073709551615 max_length_for_sort_data 1024 max_prepared_stmt_count 16382 max_relay_log_size 0 max_seeks_for_key 18446744073709551615 max_sort_length 1024 max_sp_recursion_depth 0 max_tmp_tables 32 max_user_connections 0 max_write_lock_count 18446744073709551615 memlock FALSE min_examined_row_limit 0 multi_range_count 256 myisam-recover OFF myisam_block_size 1024 myisam_data_pointer_size 6 myisam_max_extra_sort_file_size 2147483648 myisam_max_sort_file_size 9223372036853727232 myisam_repair_threads 1 myisam_sort_buffer_size 8388608 myisam_stats_method nulls_unequal myisam_use_mmap FALSE ndb-autoincrement-prefetch-sz 1 ndb-cache-check-time 0 ndb-connectstring (No default value) ndb-extra-logging 0 ndb-force-send TRUE ndb-index-stat-enable FALSE ndb-mgmd-host (No default value) ndb-nodeid 0 ndb-optimized-node-selection TRUE ndb-report-thresh-binlog-epoch-slip 3 ndb-report-thresh-binlog-mem-usage 10 ndb-shm FALSE ndb-use-copying-alter-table FALSE ndb-use-exact-count TRUE ndb-use-transactions TRUE ndb_force_send TRUE ndb_use_exact_count TRUE ndb_use_transactions TRUE net_buffer_length 16384 net_read_timeout 30 net_retry_count 10 net_write_timeout 60 new FALSE old FALSE old-alter-table FALSE old-passwords FALSE old-style-user-limits FALSE open_files_limit 1024 optimizer_prune_level 1 optimizer_search_depth 62 pid-file /home/jon/bin/mysql-5.1/var/tonfisk.pid plugin-load (No default value) plugin_dir /home/jon/bin/mysql-5.1/lib/mysql/plugin port 3306 port-open-timeout 0 preload_buffer_size 32768 profiling_history_size 15 query_alloc_block_size 8192 query_cache_limit 1048576 query_cache_min_res_unit 4096 query_cache_size 0 query_cache_type 1 query_cache_wlock_invalidate FALSE query_prealloc_size 8192 range_alloc_block_size 4096 read_buffer_size 131072 read_only FALSE read_rnd_buffer_size 262144 record_buffer 131072 relay-log (No default value) relay-log-index (No default value) relay-log-info-file relay-log.info relay_log_purge TRUE relay_log_space_limit 0 replicate-same-server-id FALSE report-host (No default value) report-password (No default value) report-port 3306 report-user (No default value) rpl-recovery-rank 0 safe-user-create FALSE secure-auth FALSE secure-file-priv (No default value) server-id 0 show-slave-auth-info FALSE skip-grant-tables FALSE skip-slave-start FALSE slave-exec-mode STRICT slave-load-tmpdir /tmp slave_compressed_protocol FALSE slave_net_timeout 3600 slave_transaction_retries 10 slow-query-log FALSE slow_launch_time 2 slow_query_log_file (No default value) socket /tmp/mysql.sock sort_buffer_size 2097144 sporadic-binlog-dump-fail FALSE sql-mode OFF symbolic-links TRUE sync-binlog 0 sync-frm TRUE sysdate-is-now FALSE table_definition_cache 256 table_lock_wait_timeout 50 table_open_cache 64 tc-heuristic-recover (No default value) temp-pool TRUE thread_cache_size 0 thread_concurrency 10 thread_stack 262144 timed_mutexes FALSE time_format %H:%i:%s tmpdir (No default value) tmp_table_size 16777216 transaction_alloc_block_size 8192 transaction_prealloc_size 4096 updatable_views_with_limit 1 use-symbolic-links TRUE verbose TRUE wait_timeout 28800 warnings 1
For a mysqld server that is currently running, you can see the current values of its system variables by connecting to it and issuing this statement:
mysql> SHOW VARIABLES;
You can also see some statistical and status indicators for a running server by issuing this statement:
mysql> SHOW STATUS;
System variable and status information also can be obtained using mysqladmin:
shell>mysqladmin variablesshell>mysqladmin extended-status
For a full description of all system and status variables, see Section 5.1.4, “Server System Variables”, and Section 5.1.6, “Server Status Variables”.
MySQL uses algorithms that are very scalable, so you can usually run with very little memory. However, normally you get better performance by giving MySQL more memory.
When tuning a MySQL server, the two most important variables to
configure are key_buffer_size
and table_open_cache. You
should first feel confident that you have these set
appropriately before trying to change any other variables.
The following examples indicate some typical variable values for different runtime configurations.
If you have at least 256MB of memory and many tables and want maximum performance with a moderate number of clients, you should use something like this:
shell>mysqld_safe --key_buffer_size=64M --table_open_cache=256 \--sort_buffer_size=4M --read_buffer_size=1M &
If you have only 128MB of memory and only a few tables, but you still do a lot of sorting, you can use something like this:
shell> mysqld_safe --key_buffer_size=16M --sort_buffer_size=1M
If there are very many simultaneous connections, swapping problems may occur unless mysqld has been configured to use very little memory for each connection. mysqld performs better if you have enough memory for all connections.
With little memory and lots of connections, use something like this:
shell>mysqld_safe --key_buffer_size=512K --sort_buffer_size=100K \--read_buffer_size=100K &
Or even this:
shell>mysqld_safe --key_buffer_size=512K --sort_buffer_size=16K \--table_open_cache=32 --read_buffer_size=8K \--net_buffer_length=1K &
If you are performing GROUP BY or
ORDER BY operations on tables that are much
larger than your available memory, you should increase the value
of read_rnd_buffer_size to
speed up the reading of rows following sorting operations.
You can make use of the example option files included with your MySQL distribution; see Section 4.2.3.3.2, “Preconfigured Option Files”.
If you specify an option on the command line for mysqld or mysqld_safe, it remains in effect only for that invocation of the server. To use the option every time the server runs, put it in an option file.
To see the effects of a parameter change, do something like this:
shell> mysqld --key_buffer_size=32M --verbose --help
The variable values are listed near the end of the output. Make
sure that the --verbose and
--help options are last.
Otherwise, the effect of any options listed after them on the
command line are not reflected in the output.
For information on tuning the InnoDB storage
engine, see Section 13.6.13.1, “InnoDB Performance Tuning Tips”.
Connection manager threads handle client connection requests on the network interfaces that the server listens to. On all platforms, one manager thread handles TCP/IP connection requests. On Unix, this manager thread also handles Unix socket file connection requests. On Windows, a manager thread handles shared-memory connection requests, and another handles named-pipe connection requests. The server does not create threads to handle interfaces that it does not listen to. For example, a Windows server that does not have support for named-pipe connections enabled does not create a thread to handle them.
Connection manager threads associate each client connection with a thread dedicated to it that handles authentication and request processing for that connection. Manager threads create a new thread when necessary but try to avoid doing so by consulting the thread cache first to see whether it contains a thread that can be used for the connection. When a connection ends, its thread is returned to the thread cache if the cache is not full.
In this connection thread model, there are as many threads as there are clients currently connected, which has some disadvantages when server workload must scale to handle large numbers of connections. For example, thread creation and disposal becomes expensive. Also, each thread requires server and kernel resources, such as stack space. To accommodate a large number of simultaneous connections, the stack size per thread must be kept small, leading to a situation where it is either too small or the server consumes large amounts of memory. Exhaustion of other resources can occur as well, and scheduling overhead can become significant.
To control and monitor how the server manages threads that handle client connections, several system and status variables are relevant. (See Section 5.1.4, “Server System Variables”, and Section 5.1.6, “Server Status Variables”.)
The thread cache has a size determined by the
thread_cache_size system
variable. The default value is 0 (no caching), which causes a
thread to be set up for each new connection and disposed of when
the connection terminates. Set
thread_cache_size to
N to enable
N inactive connection threads to be
cached. thread_cache_size can
be set at server startup or changed while the server runs. A
connection thread becomes inactive when the client connection
with which it was associated terminates.
To monitor the number of threads in the cache and how many
threads have been created because a thread could not be taken
from the cache, monitor the
Threads_cached and
Threads_created status
variables.
You can set max_connections at
server startup or at runtime to control the maximum number of
clients that can connect simultaneously.
When the thread stack is too small, this limits the complexity
of the SQL statements which the server can handle, the recursion
depth of stored procedures, and other memory-consuming actions.
To set a stack size of N bytes for
each thread, start the server with
--thread_stack=.
N
The following list indicates some of the ways that the mysqld server uses memory. Where applicable, the name of the system variable relevant to the memory use is given:
All threads share the MyISAM
key buffer; its size is determined by the
key_buffer_size variable.
Other buffers used by the server are allocated as needed.
See Section 7.9.2, “Tuning Server Parameters”.
Each thread that is used to manage client connections uses some thread-specific space. The following list indicates these and which variables control their size:
A stack (variable
thread_stack)
A connection buffer (variable
net_buffer_length)
A result buffer (variable
net_buffer_length)
The connection buffer and result buffer each begin with a
size equal to
net_buffer_length bytes,
but are dynamically enlarged up to
max_allowed_packet bytes as
needed. The result buffer shrinks to
net_buffer_length bytes
after each SQL statement. While a statement is running, a
copy of the current statement string is also allocated.
All threads share the same base memory.
When a thread is no longer needed, the memory allocated to it is released and returned to the system unless the thread goes back into the thread cache. In that case, the memory remains allocated.
Before MySQL 5.1.4, only compressed
MyISAM tables are memory mapped. As of
MySQL 5.1.4, the
myisam_use_mmap system
variable can be set to 1 to enable memory-mapping for all
MyISAM tables.
Each request that performs a sequential scan of a table
allocates a read buffer (variable
read_buffer_size).
When reading rows in an arbitrary sequence (for example,
following a sort), a random-read
buffer (variable
read_rnd_buffer_size) may
be allocated to avoid disk seeks.
All joins are executed in a single pass, and most joins can
be done without even using a temporary table. Most temporary
tables are memory-based hash tables. Temporary tables with a
large row length (calculated as the sum of all column
lengths) or that contain BLOB
columns are stored on disk.
If an internal in-memory temporary table becomes too large,
MySQL handles this automatically by changing the table from
in-memory to on-disk format, to be handled by the
MyISAM storage engine. You can increase
the permissible temporary table size as described in
Section 7.8.4, “How MySQL Uses Internal Temporary Tables”.
Most requests that perform a sort allocate a sort buffer and zero to two temporary files depending on the result set size. See Section C.5.4.4, “Where MySQL Stores Temporary Files”.
Almost all parsing and calculating is done in thread-local and reusable memory pools. No memory overhead is needed for small items, so the normal slow memory allocation and freeing is avoided. Memory is allocated only for unexpectedly large strings.
For each MyISAM table that is opened, the
index file is opened once; the data file is opened once for
each concurrently running thread. For each concurrent
thread, a table structure, column structures for each
column, and a buffer of size 3 *
are allocated (where
NN is the maximum row length, not
counting BLOB columns). A
BLOB column requires five to
eight bytes plus the length of the
BLOB data. The
MyISAM storage engine maintains one extra
row buffer for internal use.
For each table having BLOB
columns, a buffer is enlarged dynamically to read in larger
BLOB values. If you scan a
table, a buffer as large as the largest
BLOB value is allocated.
Handler structures for all in-use tables are saved in a
cache and managed as a FIFO. The initial cache size is taken
from the value of the
table_open_cache system
variable. If a table has been used by two running threads at
the same time, the cache contains two entries for the table.
See Section 7.8.2, “How MySQL Opens and Closes Tables”.
A FLUSH
TABLES statement or mysqladmin
flush-tables command closes all tables that are
not in use at once and marks all in-use tables to be closed
when the currently executing thread finishes. This
effectively frees most in-use memory.
FLUSH
TABLES does not return until all tables have been
closed.
The server caches information in memory as a result of
GRANT,
CREATE USER,
CREATE SERVER, and
INSTALL PLUGIN statements.
This memory is not released by the corresponding
REVOKE,
DROP USER,
DROP SERVER, and
UNINSTALL PLUGIN statements,
so for a server that executes many instances of the
statements that cause caching, there will be an increase in
memory use. This cached memory can be freed with
FLUSH
PRIVILEGES.
ps and other system status programs may
report that mysqld uses a lot of memory. This
may be caused by thread stacks on different memory addresses.
For example, the Solaris version of ps counts
the unused memory between stacks as used memory. To verify this,
check available swap with swap -s. We test
mysqld with several memory-leakage detectors
(both commercial and Open Source), so there should be no memory
leaks.
Disk seeks are a huge performance bottleneck. This problem becomes more apparent when the amount of data starts to grow so large that effective caching becomes impossible. For large databases where you access data more or less randomly, you can be sure that you need at least one disk seek to read and a couple of disk seeks to write things. To minimize this problem, use disks with low seek times.
Increase the number of available disk spindles (and thereby reduce the seek overhead) by either symlinking files to different disks or striping the disks:
Using symbolic links
This means that, for MyISAM tables,
you symlink the index file and data files from their
usual location in the data directory to another disk
(that may also be striped). This makes both the seek and
read times better, assuming that the disk is not used
for other purposes as well. See
Section 7.9.6, “Using Symbolic Links”.
Striping means that you have many disks and put the
first block on the first disk, the second block on the
second disk, and the N-th
block on the ()
disk, and so on. This means if your normal data size is
less than the stripe size (or perfectly aligned), you
get much better performance. Striping is very dependent
on the operating system and the stripe size, so
benchmark your application with different stripe sizes.
See Section 7.1.4, “Using Your Own Benchmarks”.
N MOD
number_of_disks
The speed difference for striping is very dependent on the parameters. Depending on how you set the striping parameters and number of disks, you may get differences measured in orders of magnitude. You have to choose to optimize for random or sequential access.
For reliability, you may want to use RAID 0+1 (striping plus
mirroring), but in this case, you need 2 ×
N drives to hold
N drives of data. This is
probably the best option if you have the money for it.
However, you may also have to invest in some
volume-management software to handle it efficiently.
A good option is to vary the RAID level according to how
critical a type of data is. For example, store
semi-important data that can be regenerated on a RAID 0
disk, but store really important data such as host
information and logs on a RAID 0+1 or RAID
N disk. RAID
N can be a problem if you have
many writes, due to the time required to update the parity
bits.
On Linux, you can get much more performance by using
hdparm to configure your disk's
interface. (Up to 100% under load is not uncommon.) The
following hdparm options should be quite
good for MySQL, and probably for many other applications:
hdparm -m 16 -d 1
Note that performance and reliability when using this
command depend on your hardware, so we strongly suggest that
you test your system thoroughly after using
hdparm. Please consult the
hdparm manual page for more information.
If hdparm is not used wisely, file system
corruption may result, so back up everything before
experimenting!
You can also set the parameters for the file system that the database uses:
If you do not need to know when files were last accessed
(which is not really useful on a database server), you can
mount your file systems with the -o noatime
option. That skips updates to the last access time in inodes
on the file system, which avoids some disk seeks.
On many operating systems, you can set a file system to be
updated asynchronously by mounting it with the -o
async option. If your computer is reasonably
stable, this should give you more performance without
sacrificing too much reliability. (This flag is on by
default on Linux.)
You can move tables and databases from the database directory to other locations and replace them with symbolic links to the new locations. You might want to do this, for example, to move a database to a file system with more free space or increase the speed of your system by spreading your tables to different disk.
The recommended way to do this is simply to symlink databases to a different disk. Symlink tables only as a last resort.
On Unix, the way to symlink a database is first to create a directory on some disk where you have free space and then to create a symlink to it from the MySQL data directory.
shell>mkdir /dr1/databases/testshell>ln -s /dr1/databases/test/path/to/datadir
MySQL does not support linking one directory to multiple
databases. Replacing a database directory with a symbolic link
works as long as you do not make a symbolic link between
databases. Suppose that you have a database
db1 under the MySQL data directory, and
then make a symlink db2 that points to
db1:
shell>cdshell>/path/to/datadirln -s db1 db2
The result is that, or any table tbl_a in
db1, there also appears to be a table
tbl_a in db2. If one
client updates db1.tbl_a and another client
updates db2.tbl_a, problems are likely to
occur.
However, if you really need to do this, it is possible by
altering the source file
mysys/my_symlink.c, in which you should
look for the following statement:
if (!(MyFlags & MY_RESOLVE_LINK) ||
(!lstat(filename,&stat_buff) && S_ISLNK(stat_buff.st_mode)))
Change the statement to this:
if (1)
You should not symlink tables on systems that do not have a
fully operational realpath() call. (Linux
and Solaris support realpath()). You can
check whether your system supports symbolic links by issuing a
SHOW VARIABLES LIKE 'have_symlink'
statement.
Symlinks are fully supported only for
MyISAM tables. For files used by tables for
other storage engines, you may get strange problems if you try
to use symbolic links.
The handling of symbolic links for MyISAM
tables works as follows:
In the data directory, you always have the table format
(.frm) file, the data
(.MYD) file, and the index
(.MYI) file. The data file and index
file can be moved elsewhere and replaced in the data
directory by symlinks. The format file cannot.
You can symlink the data file and the index file independently to different directories.
You can instruct a running MySQL server to perform the
symlinking by using the DATA DIRECTORY
and INDEX DIRECTORY options to
CREATE TABLE. See
Section 12.1.17, “CREATE TABLE Syntax”. Alternatively, symlinking
can be accomplished manually from the command line using
ln -s if mysqld is
not running.
Beginning with MySQL 5.1.24, the path used with either
or both of the DATA DIRECTORY and
INDEX DIRECTORY options may not
include the MySQL data directory.
(Bug#32167)
myisamchk does not replace a symlink
with the data file or index file. It works directly on the
file to which the symlink points. Any temporary files are
created in the directory where the data file or index file
is located. The same is true for the
ALTER TABLE,
OPTIMIZE TABLE, and
REPAIR TABLE statements.
When you drop a table that is using symlinks,
both the symlink and the file to which the
symlink points are dropped. This is an
extremely good reason why you should
not run mysqld
as the system root or permit system
users to have write access to MySQL database
directories.
If you rename a table with ALTER TABLE ...
RENAME or RENAME
TABLE and you do not move the table to another
database, the symlinks in the database directory are
renamed to the new names and the data file and index file
are renamed accordingly.
If you use ALTER TABLE ... RENAME or
RENAME TABLE to move a
table to another database, the table is moved to the other
database directory. If the table name changed, the
symlinks in the new database directory are renamed to the
new names and the data file and index file are renamed
accordingly.
If you are not using symlinks, you should use the
--skip-symbolic-links
option to mysqld to ensure that no one
can use mysqld to drop or rename a file
outside of the data directory.
Table symlink operations that are not yet supported:
ALTER TABLE ignores the
DATA DIRECTORY and INDEX
DIRECTORY table options.
BACKUP TABLE and
RESTORE TABLE do not
respect symbolic links.
The .frm file must
never be a symbolic link (as
indicated previously, only the data and index files can be
symbolic links). Attempting to do this (for example, to
make synonyms) produces incorrect results. Suppose that
you have a database db1 under the MySQL
data directory, a table tbl1 in this
database, and in the db1 directory you
make a symlink tbl2 that points to
tbl1:
shell>cdshell>/path/to/datadir/db1ln -s tbl1.frm tbl2.frmshell>ln -s tbl1.MYD tbl2.MYDshell>ln -s tbl1.MYI tbl2.MYI
Problems result if one thread reads
db1.tbl1 and another thread updates
db1.tbl2:
The query cache is “fooled” (it has no
way of knowing that tbl1 has not
been updated, so it returns outdated results).
ALTER statements on
tbl2 fail.
Symbolic links are enabled by default for all Windows servers.
This enables you to put a database directory on a different
disk by setting up a symbolic link to it. This is similar to
the way that database symbolic links work on Unix, although
the procedure for setting up the link is different. If you do
not need symbolic links, you can disable them using the
--skip-symbolic-links
option.
On Windows, create a symbolic link to a MySQL database by
creating a file in the data directory that contains the path
to the destination directory. The file should be named
,
where db_name.symdb_name is the database name.
Suppose that the MySQL data directory is
C:\mysql\data and you want to have
database foo located at
D:\data\foo. Set up a symlink using this
procedure
Make sure that the D:\data\foo
directory exists by creating it if necessary. If you
already have a database directory named
foo in the data directory, you should
move it to D:\data. Otherwise, the
symbolic link will be ineffective. To avoid problems, make
sure that the server is not running when you move the
database directory.
Create a text file
C:\mysql\data\foo.sym that contains
the path name D:\data\foo\.
The path name to the new database and tables should be
absolute. If you specify a relative path, the location
will be relative to the foo.sym
file.
After this, all tables created in the database
foo are created in
D:\data\foo.
The following limitations apply to the use of
.sym files for database symbolic linking
on Windows:
The symbolic link is not used if a directory with the same name as the database exists in the MySQL data directory.
The --innodb_file_per_table
option cannot be used.
If you run mysqld as a service, you
cannot use a mapped drive to a remote server as the
destination of the symbolic link. As a workaround, you can
use the full path
(\\servername\path\).
Some hardware/operating system architectures support memory pages greater than the default (usually 4KB). The actual implementation of this support depends on the underlying hardware and operating system. Applications that perform a lot of memory accesses may obtain performance improvements by using large pages due to reduced Translation Lookaside Buffer (TLB) misses.
In MySQL, large pages can be used by InnoDB, to allocate memory for its buffer pool and additional memory pool.
Currently, MySQL supports only the Linux implementation of large page support (which is called HugeTLB in Linux).
Before large pages can be used on Linux, the kernel must be
enabled to support them and it is necessary to configure the
HugeTLB memory pool. For reference, the HugeTBL API is
documented in the
Documentation/vm/hugetlbpage.txt file of
your Linux sources.
The kernel for some recent systems such as Red Hat Enterprise Linux appear to have the large pages feature enabled by default. To check whether this is true for your kernel, use the following command and look for output lines containing “huge”:
shell> cat /proc/meminfo | grep -i huge
HugePages_Total: 0
HugePages_Free: 0
HugePages_Rsvd: 0
HugePages_Surp: 0
Hugepagesize: 4096 kB
The nonempty command output indicates that large page support is present, but the zero values indicate that no pages are configured for use.
If your kernel needs to be reconfigured to support large pages,
consult the hugetlbpage.txt file for
instructions.
Assuming that your Linux kernel has large page support enabled,
configure it for use by MySQL using the following commands.
Normally, you put these in an rc file or
equivalent startup file that is executed during the system boot
sequence, so that the commands execute each time the system
starts. The commands should execute early in the boot sequence,
before the MySQL server starts. Be sure to change the allocation
numbers and the group number as appropriate for your system.
# Set the number of pages to be used. # Each page is normally 2MB, so a value of 20 = 40MB. # This command actually allocates memory, so this much # memory must be available. echo 20 > /proc/sys/vm/nr_hugepages # Set the group number that is permitted to access this # memory (102 in this case). The mysql user must be a # member of this group. echo 102 > /proc/sys/vm/hugetlb_shm_group # Increase the amount of shmem permitted per segment # (12G in this case). echo 1560281088 > /proc/sys/kernel/shmmax # Increase total amount of shared memory. The value # is the number of pages. At 4KB/page, 4194304 = 16GB. echo 4194304 > /proc/sys/kernel/shmall
For MySQL usage, you normally want the value of
shmmax to be close to the value of
shmall.
To verify the large page configuration, check
/proc/meminfo again as described
previously. Now you should see some nonzero values:
shell> cat /proc/meminfo | grep -i huge
HugePages_Total: 20
HugePages_Free: 20
HugePages_Rsvd: 0
HugePages_Surp: 0
Hugepagesize: 4096 kB
The final step to make use of the
hugetlb_shm_group is to give the
mysql user an “unlimited” value
for the memlock limit. This can by done either by editing
/etc/security/limits.conf or by adding the
following command to your mysqld_safe script:
ulimit -l unlimited
Adding the ulimit command to
mysqld_safe causes the
root user to set the memlock limit to
unlimited before switching to the
mysql user. (This assumes that
mysqld_safe is started by
root.)
Large page support in MySQL is disabled by default. To enable
it, start the server with the
--large-pages option. For
example, you can use the following lines in your server's
my.cnf file:
[mysqld] large-pages
With this option, InnoDB uses large pages
automatically for its buffer pool and additional memory pool. If
InnoDB cannot do this, it falls back to use
of traditional memory and writes a warning to the error log:
Warning: Using conventional memory pool
To verify that large pages are being used, check
/proc/meminfo again:
shell> cat /proc/meminfo | grep -i huge
HugePages_Total: 20
HugePages_Free: 20
HugePages_Rsvd: 2
HugePages_Surp: 0
Hugepagesize: 4096 kB
When a new client connects to mysqld, mysqld spawns a new thread to handle the request. This thread first checks whether the host name is in the host name cache. If not, the thread attempts to resolve the host name:
The thread takes the IP address and resolves it to a host
name (using gethostbyaddr()). It then
takes that host name and resolves it back to the IP address
(using gethostbyname()) and compares to
ensure it is the original IP address.
If the operating system supports the thread-safe
gethostbyaddr_r() and
gethostbyname_r() calls, the thread
uses them to perform host name resolution.
If the operating system does not support the thread-safe
calls, the thread locks a mutex and calls
gethostbyaddr() and
gethostbyname() instead. In this case,
no other thread can resolve host names that are not in the
host name cache until the first thread unlocks the mutex.
You can disable DNS host name lookups by starting
mysqld with the
--skip-name-resolve option.
However, in this case, you can use only IP numbers in the MySQL
grant tables.
If you have a very slow DNS and many hosts, you can get more
performance by either disabling DNS lookups with
--skip-name-resolve or by
increasing the HOST_CACHE_SIZE define
(default value: 128) and recompiling mysqld.
You can disable the host name cache by starting the server with
the --skip-host-cache option. To
clear the host name cache, issue a
FLUSH HOSTS
statement or execute the mysqladmin
flush-hosts command.
To disallow TCP/IP connections entirely, start
mysqld with the
--skip-networking option.
When you are attempting to ascertain what your MySQL server is doing, it can be helpful to examine the process list, which is the set of threads currently executing within the server. Process list information is available from these sources:
The SHOW [FULL] PROCESSLIST statement:
Section 12.4.5.31, “SHOW PROCESSLIST Syntax”
The SHOW PROFILE statement:
Section 12.4.5.33, “SHOW PROFILES Syntax”
The INFORMATION_SCHEMA
PROCESSLIST table:
Section 20.22, “The INFORMATION_SCHEMA PROCESSLIST Table”
The mysqladmin processlist command: Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”
You can always view information about your own threads. To view
information about threads being executed for other accounts, you
must have the PROCESS privilege.
Each process list entry contains several pieces of information:
Id is the connection identifier for the
client associated with the thread.
User and Host indicate
the account associated with the thread.
db is the default database for the thread,
or NULL if none is selected.
Command and State
indicate what the thread is doing.
Most states correspond to very quick operations. If a thread stays in a given state for many seconds, there might be a problem that needs to be investigated.
Time indicates how long the thread has been
in its current state. The thread's notion of the current time
may be altered in some cases: The thread can change the time
with SET TIMESTAMP
= . For a thread
running on a slave that is processing events from the master,
the thread time is set to the time found in the events and
thus reflects current time on the master and not the slave.
value
Info contains the text of the statement
being executed by the thread, or NULL if it
is not executing one. By default, this value contains only the
first 100 characters of the statement. To see the complete
statements, use
SHOW FULL
PROCESSLIST.
The following sections list the possible
Command values, and State
values grouped by category. The meaning for some of these values
is self-evident. For others, additional description is provided.
A thread can have any of the following
Command values:
This is a thread on a master server for sending binary log contents to a slave server.
The thread is executing a change-user operation.
The thread is closing a prepared statement.
A replication slave is connected to its master.
A replication slave is connecting to its master.
The thread is executing a create-database operation.
This thread is internal to the server, not a thread that services a client connection.
The thread is generating debugging information.
The thread is a delayed-insert handler.
The thread is executing a drop-database operation.
The thread is executing a prepared statement.
The thread is fetching the results from executing a prepared statement.
The thread is retrieving information for table columns.
The thread is selecting a default database.
The thread is killing another thread.
The thread is retrieving long data in the result of executing a prepared statement.
The thread is handling a server-ping request.
The thread is preparing a prepared statement.
The thread is producing information about server threads.
The thread is executing a statement.
The thread is terminating.
The thread is flushing table, logs, or caches, or resetting status variable or replication server information.
The thread is registering a slave server.
The thread is resetting a prepared statement.
The thread is setting or resetting a client statement-execution option.
The thread is shutting down the server.
The thread is waiting for the client to send a new statement to it.
The thread is producing server-status information.
The thread is sending table contents to a slave server.
Unused.
The following list describes thread State
values that are associated with general query processing and not
more specialized activities such as replication. Many of these
are useful only for finding bugs in the server.
This occurs when the thread creates a table (including internal temporary tables), at the end of the function that creates the table. This state is used even if the table could not be created due to some error.
The thread is calculating a MyISAM table
key distributions (for example, for
ANALYZE TABLE).
The thread is checking whether the server has the required privileges to execute the statement.
The thread is performing a table check operation.
The thread has processed one command and is preparing to free memory and reset certain state variables.
The thread is flushing the changed table data to disk and closing the used tables. This should be a fast operation. If not, you should verify that you do not have a full disk and that the disk is not in very heavy use.
The thread is converting an internal temporary table from a
MEMORY table to an on-disk
MyISAM table.
The thread is processing an ALTER
TABLE statement. This state occurs after the table
with the new structure has been created but before rows are
copied into it.
If a statement has different ORDER BY and
GROUP BY criteria, the rows are sorted by
group and copied to a temporary table.
The server is copying to a temporary table in memory.
The server is copying to a temporary table on disk. The temporary result set has become too large (see Section 7.8.4, “How MySQL Uses Internal Temporary Tables”). Consequently, the thread is changing the temporary table from in-memory to disk-based format to save memory.
The thread is processing ALTER TABLE ... ENABLE
KEYS for a MyISAM table.
The thread is processing a
SELECT that is resolved using
an internal temporary table.
The thread is creating a table. This includes creation of temporary tables.
The thread is creating a temporary table in memory or on
disk. If the table is created in memory but later is
converted to an on-disk table, the state during that
operation will be Copying to tmp table on
disk.
The server is executing the first part of a multiple-table delete. It is deleting only from the first table, and saving columns and offsets to be used for deleting from the other (reference) tables.
deleting from reference tables
The server is executing the second part of a multiple-table delete and deleting the matched rows from the other tables.
The thread is processing an ALTER TABLE ... DISCARD
TABLESPACE or ALTER TABLE ... IMPORT
TABLESPACE statement.
This occurs at the end but before the cleanup of
ALTER TABLE,
CREATE VIEW,
DELETE,
INSERT,
SELECT, or
UPDATE statements.
The thread has begun executing a statement.
The thread is executing statements in the value of the
init_command system variable.
The thread has executed a command. Some freeing of items
done during this state involves the query cache. This state
is usually followed by cleaning up.
The thread is executing
FLUSH
TABLES and is waiting for all threads to close
their tables.
The server is preparing to perform a natural-language full-text search.
This occurs before the initialization of
ALTER TABLE,
DELETE,
INSERT,
SELECT, or
UPDATE statements. Actions
taken by the server in this state include flushing the
binary log, the InnoDB log, and some
query cache cleanup operations.
For the end state, the following
operations could be happening:
Removing query cache entries after data in a table is changed
Writing an event to the binary log
Freeing memory buffers, including for blobs
Someone has sent a KILL
statement to the thread and it should abort next time it
checks the kill flag. The flag is checked in each major loop
in MySQL, but in some cases it might still take a short time
for the thread to die. If the thread is locked by some other
thread, the kill takes effect as soon as the other thread
releases its lock.
The query is locked by another query.
The thread is writing a statement to the slow-query log.
This state is used for the SHOW
PROCESSLIST state.
The initial state for a connection thread until the client has been authenticated successfully.
The server is enabling or disabling a table index.
The thread is trying to open a table. This is should be very
fast procedure, unless something prevents opening. For
example, an ALTER TABLE or a
LOCK
TABLE statement can prevent opening a table until
the statement is finished. It is also worth checking that
your table_open_cache value
is large enough.
The server is performing initial optimizations for a query.
This state occurs during query optimization.
The thread is removing unneeded relay log files.
This state occurs after processing a query but before the
freeing items state.
The server is reading a packet from the network.
The query was using
SELECT
DISTINCT in such a way that MySQL could not
optimize away the distinct operation at an early stage.
Because of this, MySQL requires an extra stage to remove all
duplicated rows before sending the result to the client.
The thread is removing an internal temporary table after
processing a SELECT
statement. This state is not used if no temporary table was
created.
The thread is renaming a table.
The thread is processing an ALTER
TABLE statement, has created the new table, and is
renaming it to replace the original table.
The thread got a lock for the table, but noticed after getting the lock that the underlying table structure changed. It has freed the lock, closed the table, and is trying to reopen it.
The repair code is using a sort to create indexes.
The thread has completed a multi-threaded repair for a
MyISAM table.
The repair code is using creating keys one by one through
the key cache. This is much slower than Repair by
sorting.
The thread is rolling back a transaction.
For MyISAM table operations such as
repair or analysis, the thread is saving the new table state
to the .MYI file header. State includes
information such as number of rows, the
AUTO_INCREMENT counter, and key
distributions.
The thread is doing a first phase to find all matching rows
before updating them. This has to be done if the
UPDATE is changing the index
that is used to find the involved rows.
Sending data
The thread is processing rows for a
SELECT statement and also is
sending data to the client.
The thread is beginning an ALTER
TABLE operation.
The thread is doing a sort to satisfy a GROUP
BY.
The thread is doing a sort to satisfy a ORDER
BY.
The thread is sorting index pages for more efficient access
during a MyISAM table optimization
operation.
For a SELECT statement, this
is similar to Creating sort index, but
for nontemporary tables.
The server is calculating statistics to develop a query execution plan. If a thread is in this state for a long time, the server is probably disk-bound performing other work.
The thread is going to request or is waiting for an internal
or external system lock for the table. If this state is
being caused by requests for external locks and you are not
using multiple mysqld servers that are
accessing the same tables, you can disable external system
locks with the
--skip-external-locking
option. However, external locking is disabled by default, so
it is likely that this option will have no effect.
The next thread state after System lock.
The thread has acquired an external lock and is going to
request an internal table lock.
The thread is searching for rows to update and is updating them.
The server is executing the first part of a multiple-table update. It is updating only the first table, and saving columns and offsets to be used for updating the other (reference) tables.
The server is executing the second part of a multiple-table update and updating the matched rows from the other tables.
The thread is going to request or is waiting for an advisory
lock requested with a
GET_LOCK() call. For
SHOW PROFILE, this state
means the thread is requesting the lock (not waiting for
it).
The thread has invoked a
SLEEP() call.
Waiting for release of readlock
The thread is waiting for a global read lock obtained by
another thread (with
FLUSH TABLES WITH
READ LOCK) to be released.
Waiting for tables, Waiting for
table
The thread got a notification that the underlying structure for a table has changed and it needs to reopen the table to get the new structure. However, to reopen the table, it must wait until all other threads have closed the table in question.
This notification takes place if another thread has used
FLUSH
TABLES or one of the following statements on the
table in question: FLUSH TABLES
,
tbl_nameALTER TABLE,
RENAME TABLE,
REPAIR TABLE,
ANALYZE TABLE, or
OPTIMIZE TABLE.
A generic state in which the thread is waiting for a condition to become true. No specific state information is available.
The thread has issued a
FLUSH TABLES WITH
READ LOCK statement to obtain a global read lock
and is waiting to obtain the lock.
The server is writing a packet to the network.
These thread states are associated with processing for
DELAYED inserts (see
Section 12.2.5.2, “INSERT DELAYED Syntax”). Some states are associated
with connection threads that process INSERT
DELAYED statements from clients. Other states are
associated with delayed-insert handler threads that insert the
rows. There is a delayed-insert handler thread for each table
for which INSERT DELAYED
statements are issued.
States associated with a connection thread that processes an
INSERT DELAYED statement from the
client:
The thread is preparing to feed rows to the delayed-insert handler thread.
The thread is creating a handler for
DELAYED inserts.
This occurs before the allocating local
table state and after the waiting for
handler lock state, when the connection thread
gets access to the delayed-insert handler thread.
This occurs after the waiting for handler
open state. The delayed-insert handler thread has
signaled that it has ended its initialization phase, which
includes opening the table for delayed inserts.
The thread is adding a new row to the list of rows that the delayed-insert handler thread must insert.
The thread is getting ready to start updating the table.
This occurs during the initialization phase when the thread is trying to find the delayed-insert handler thread for the table, and before attempting to gain access to the list of delayed-insert threads.
An INSERT DELAYED handler has
processed all pending inserts and is waiting for new ones.
This occurs before the allocating local
table state when the connection thread waits for
access to the delayed-insert handler thread.
This occurs after the Creating delayed
handler state and before the got old
table state. The delayed-insert handler thread has
just been started, and the connection thread is waiting for
it to initialize.
States associated with a delayed-insert handler thread that inserts the rows:
The state that occurs just before inserting rows into the table.
After inserting a number of rows, the delayed-insert thread sleeps to let other threads do work.
A delayed-insert handler is trying to get a lock for the table to insert rows.
A delayed-insert handler is waiting for a connection thread
to add rows to the queue (see storing row into
queue).
These thread states are associated with the query cache (see Section 7.6.3, “The MySQL Query Cache”).
checking privileges on cached query
The server is checking whether the user has privileges to access a cached query result.
checking query cache for query
The server is checking whether the current query is present in the query cache.
invalidating query cache entries
Query cache entries are being marked invalid because the underlying tables have changed.
sending cached result to client
The server is taking the result of a query from the query cache and sending it to the client.
The server is storing the result of a query in the query cache.
The following list shows the most common states you may see in
the State column for the master's
Binlog Dump thread. If you see no
Binlog Dump threads on a master server, this
means that replication is not running—that is, that no
slaves are currently connected.
Binary logs consist of events, where an event is usually an update plus some other information. The thread has read an event from the binary log and is now sending it to the slave.
Finished reading one binlog; switching to next
binlog
The thread has finished reading a binary log file and is opening the next one to send to the slave.
Has sent all binlog to slave; waiting for binlog to
be updated
The thread has read all outstanding updates from the binary logs and sent them to the slave. The thread is now idle, waiting for new events to appear in the binary log resulting from new updates occurring on the master.
Waiting to finalize termination
A very brief state that occurs as the thread is stopping.
The following list shows the most common states you see in the
State column for a slave server I/O thread.
This state also appears in the Slave_IO_State
column displayed by SHOW SLAVE
STATUS, so you can get a good view of what is
happening by using that statement.
The initial state before Connecting to
master.
The thread is attempting to connect to the master.
A state that occurs very briefly, after the connection to the master is established.
A state that occurs very briefly after the connection to the master is established.
A state that occurs very briefly, after the connection to the master is established. The thread sends to the master a request for the contents of its binary logs, starting from the requested binary log file name and position.
Waiting to reconnect after a failed binlog dump
request
If the binary log dump request failed (due to
disconnection), the thread goes into this state while it
sleeps, then tries to reconnect periodically. The interval
between retries can be specified using the
CHANGE MASTER TO statement or
the --master-connect-retry
option.
Reconnecting after a failed binlog dump
request
The thread is trying to reconnect to the master.
Waiting for master to send event
The thread has connected to the master and is waiting for
binary log events to arrive. This can last for a long time
if the master is idle. If the wait lasts for
slave_net_timeout seconds,
a timeout occurs. At that point, the thread considers the
connection to be broken and makes an attempt to reconnect.
Queueing master event to the relay log
The thread has read an event and is copying it to the relay log so that the SQL thread can process it.
Waiting to reconnect after a failed master event
read
An error occurred while reading (due to disconnection). The
thread is sleeping for the number of seconds set by the
CHANGE MASTER TO statement or
--master-connect-retry option
(default 60) before attempting to reconnect.
Reconnecting after a failed master event
read
The thread is trying to reconnect to the master. When
connection is established again, the state becomes
Waiting for master to send event.
Waiting for the slave SQL thread to free enough
relay log space
You are using a nonzero
relay_log_space_limit
value, and the relay logs have grown large enough that their
combined size exceeds this value. The I/O thread is waiting
until the SQL thread frees enough space by processing relay
log contents so that it can delete some relay log files.
Waiting for slave mutex on exit
A state that occurs briefly as the thread is stopping.
The following list shows the most common states you may see in
the State column for a slave server SQL
thread:
Waiting for the next event in relay log
The initial state before Reading event from the
relay log.
Reading event from the relay log
The thread has read an event from the relay log so that the event can be processed.
Has read all relay log; waiting for the slave I/O
thread to update it
The thread has processed all events in the relay log files, and is now waiting for the I/O thread to write new events to the relay log.
The thread is executing a
LOAD DATA
INFILE statement and is creating a temporary file
containing the data from which the slave will read rows.
Waiting for slave mutex on exit
A very brief state that occurs as the thread is stopping.
The State column for the I/O thread may also
show the text of a statement. This indicates that the thread has
read an event from the relay log, extracted the statement from
it, and is executing it.
These thread states occur on a replication slave but are associated with connection threads, not with the I/O or SQL threads.
The thread is processing a CHANGE
MASTER TO statement.
Creating table from master dump
The slave is creating a table using the
CREATE TABLE statement
contained in the dump from the master. Used for
LOAD TABLE FROM MASTER and
LOAD DATA FROM MASTER.
The thread is processing a SLAVE STOP
statement.
This state occurs after Creating table from master
dump.
Reading master dump table data
This state occurs after Opening master dump
table.
Rebuilding the index on master dump table
This state occurs after Reading master dump table
data.
The thread is starting the slave threads after processing a
successful LOAD DATA FROM
MASTER load operation.
The thread is processing events for binary logging.
Processing events from schema table
The thread is doing the work of schema replication.
Syncing ndb table schema operation and
binlog
This is used to have a correct binary log of schema operations for NDB.
Waiting for event from ndbcluster
The server is acting as an SQL node in a MySQL Cluster, and is connected to a cluster management node.
Waiting for ndbcluster binlog update to reach
current position
The thread is waiting for a schema epoch (that is, a global checkpoint).
These states occur for the Event Scheduler thread, threads that are created to execute scheduled events, or threads that terminate the scheduler.
The scheduler thread or a thread that was executing an event is terminating and is about to end.
The scheduler thread or a thread that will execute an event has been initialized.
The scheduler has a nonempty event queue but the next activation is in the future.
The thread issued SET GLOBAL
event_scheduler=OFF and is waiting for the
scheduler to stop.
The scheduler's event queue is empty and it is sleeping.