|
|
Table of Contents
SELECT
and Other StatementsEXPLAIN
SELECT
QueriesWHERE
Clause OptimizationIS NULL
OptimizationDISTINCT
OptimizationLEFT JOIN
and RIGHT JOIN
OptimizationORDER BY
OptimizationGROUP BY
OptimizationLIMIT
OptimizationINSERT
StatementsUPDATE
StatementsDELETE
StatementsMyISAM
Key CacheMyISAM
Index Statistics CollectionOptimization 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.
This chapter tries to explain and give some examples of different ways to optimize MySQL. Remember, however, that there are always additional ways to make the system even faster, although they may require increasing effort to achieve.
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 allows 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 14, Storage Engines and Table Types.
MySQL can work with both transactional and non-transactional
tables. To make it easier to work smoothly with
non-transactional 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 numerical 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.9.6, “How MySQL Deals with Constraints”,
Section 5.2.5, “The Server SQL Mode”, and Section 13.2.4, “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.4, “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. Oracle, on the other
hand, has a big problem when you try to access rows that you
have recently updated (until they are flushed to disk).
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 9.4, “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 5.14, “The MySQL Query Cache”.
This section describes an early application for MySQL.
During MySQL initial development, the features of MySQL were made to fit our largest customer, which handled data warehousing for a couple of the largest retailers in Sweden.
From all stores, we got weekly summaries of all bonus card transactions, and were expected to provide useful information for the store owners to help them find how their advertising campaigns were affecting their own customers.
The volume of data was quite huge (about seven million summary transactions per month), and we had data for 4–10 years that we needed to present to the users. We got weekly requests from our customers, who wanted instant access to new reports from this data.
We solved this problem by storing all information per month in compressed “transaction tables.” We had a set of simple macros that generated summary tables grouped by different criteria (product group, customer id, store, and so on) from the tables in which the transactions were stored. The reports were Web pages that were dynamically generated by a small Perl script. This script parsed a Web page, executed the SQL statements in it, and inserted the results. We would have used PHP or mod_perl instead, but they were not available at the time.
For graphical data, we wrote a simple tool in C that could process SQL query results and produce GIF images based on those results. This tool also was dynamically executed from the Perl script that parses the Web pages.
In most cases, a new report could be created simply by copying an existing script and modifying the SQL query that it used. In some cases, we needed to add more columns to an existing summary table or generate a new one. This also was quite simple because we kept all transaction-storage tables on disk. (This amounted to about 50GB of transaction tables and 200GB of other customer data.)
We also let our customers access the summary tables directly with ODBC so that the advanced users could experiment with the data themselves.
This system worked well and we had no problems handling the data with quite modest Sun Ultra SPARCstation hardware (2×200MHz). Eventually the system was migrated to Linux.
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.8.3, “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.13, “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-bench
shell>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
You can find the results from crash-me for many different database servers at http://dev.mysql.com/tech-resources/crash-me.php. For more information about benchmark results, visit http://dev.mysql.com/tech-resources/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.4, “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. You can use Super Smack, available at http://jeremy.zawodny.com/mysql/super-smack/. As suggested by its name, it can bring a system to its knees, so make sure to use it only on your development systems.
EXPLAIN
SELECT
QueriesWHERE
Clause OptimizationIS NULL
OptimizationDISTINCT
OptimizationLEFT JOIN
and RIGHT JOIN
OptimizationORDER BY
OptimizationGROUP BY
OptimizationLIMIT
OptimizationINSERT
StatementsUPDATE
StatementsDELETE
Statements
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.
EXPLAIN tbl_name
Or:
EXPLAIN [EXTENDED] SELECT select_options
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_name
DESCRIBE
or
tbl_name
SHOW COLUMNS FROM
.
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.
This section describes the second use of
EXPLAIN
for obtaining query execution plan
information. For a description of the
DESCRIBE
and SHOW COLUMNS
statements, see Section 13.3.1, “DESCRIBE
Syntax”, and
Section 13.5.4.3, “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 force 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
.
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 13.5.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 single-sweep multi-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.
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:
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) |
DEPENDENT
typically signifies the use of
a correlated subquery. See
Section 13.2.8.7, “Correlated Subqueries”.
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_name
WHEREprimary_key
=1; SELECT * FROMtbl_name
WHEREprimary_key_part1
=1 ANDprimary_key_part2
=2;
eq_ref
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
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_table
WHEREref_table
.key_column
=other_table
.column
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column_part1
=other_table
.column
ANDref_table
.key_column_part2
=1;
ref
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_table
WHEREkey_column
=expr
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column
=other_table
.column
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column_part1
=other_table
.column
ANDref_table
.key_column_part2
=1;
ref_or_null
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_table
WHEREkey_column
=expr
ORkey_column
IS NULL;
index_merge
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.2.6, “Index Merge Optimization”.
unique_subquery
This type replaces ref
for some
IN
subqueries of the following form:
value
IN (SELECTprimary_key
FROMsingle_table
WHEREsome_expr
)
unique_subquery
is just an index
lookup function that replaces the subquery completely
for better efficiency.
index_subquery
This join type is similar to
unique_subquery
. It replaces
IN
subqueries, but it works for
non-unique indexes in subqueries of the following form:
value
IN (SELECTkey_column
FROMsingle_table
WHEREsome_expr
)
range
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_name
WHEREkey_column
= 10; SELECT * FROMtbl_name
WHEREkey_column
BETWEEN 10 and 20; SELECT * FROMtbl_name
WHEREkey_column
IN (10,20,30); SELECT * FROMtbl_name
WHEREkey_part1
= 10 ANDkey_part2
IN (10,20,30);
index
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.
ALL
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 allow 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 13.1.2, “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. The key is
NULL
if no index was chosen. 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 13.2.7, “SELECT
Syntax”.
For MyISAM
and BDB
tables, running ANALYZE TABLE
helps the
optimizer choose better indexes. For
MyISAM
tables, myisamchk
--analyze does the same. See
Section 13.5.2.1, “ANALYZE TABLE
Syntax”, and
Section 5.10.4, “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.
Extra
This column contains additional information about how MySQL resolves the query. Here is an explanation of the values that can appear in this column:
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.
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.2.5, “Range Optimization”, and
Section 7.2.6, “Index Merge Optimization”, with the
exception that all column values for the preceding table
are known and considered to be constants.
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.2.12, “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.
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
.
If you want to make your queries as fast as possible,
you should look out for Extra
values
of Using filesort
and Using
temporary
.
Using sort_union(...)
, Using
union(...)
, Using
intersect(...)
These indicate how index scans are merged for the
index_merge
join type. See
Section 7.2.6, “Index Merge Optimization”, for more
information.
Using index for group-by
Similar to the Using index
way of
accessing a table, 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.2.13, “GROUP BY
Optimization”.
Using where with pushed condition
This item applies to NDB Cluster
tables only. It means that MySQL
Cluster is using condition
pushdown to improve the efficiency of a
direct comparison (=
) between a
non-indexed column and a constant. In such cases, the
condition is “pushed down” to the cluster's
data nodes where it is evaluated in all partitions
simultaneously. This eliminates the need to send
non-matching 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.
Suppose that you have a Cluster table defined as follows:
CREATE TABLE t1 ( a INT, b INT, KEY(a) ) ENGINE=NDBCLUSTER;
In this case, condition pushdown can be used with a query such as this one:
SELECT a,b FROM t1 WHERE b = 10;
This can be seen in the output of EXPLAIN
SELECT
, as shown here:
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
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;
With regard to the first of these two queries, condition
pushdown is not applicable because an index exists on
column a
. In the case of the second
query, a condition pushdown cannot be employed because
the comparison involving the non-indexed column
b
is an indirect one. (However, it
would apply if you were to reduce b + 1 =
10
to b = 9
in the
WHERE
clause.)
However, a condition pushdown may also be employed when
an indexed column 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
With regard to condition pushdown, keep in mind that:
Condition pushdown is relevant to MySQL Cluster only, and does not occur when executing queries against tables using any other storage engine.
Condition pushdown capability is not used by
default. To enable it, you can start
mysqld with the
--engine-condition-pushdown
option,
or execute the following statement:
SET engine_condition_pushdown=On;
Condition pushdown, Using where with pushed
condition
, and
engine_condition_pushdown
were all
introduced in MySQL 5.0 Cluster.
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.5.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 (key map: 35)
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 (key map: 1) et_1 ALL PRIMARY NULL NULL NULL 74 range checked for each record (key map: 1) 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.
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 an
index 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.5.2, “Tuning Server Parameters”.
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.4.5, “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 non-constant expression. You can check the
result from the table analysis by using SHOW INDEX
FROM
and
examining the tbl_name
Cardinality
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_name
WHEREkey_part1
=constant
; SELECT ... FROMtbl_name
ORDER BYkey_part1
,key_part2
,... LIMIT 10; SELECT ... FROMtbl_name
ORDER BYkey_part1
DESC,key_part2
DESC, ... LIMIT 10;
MySQL resolves the following queries using only the index tree, assuming that the indexed columns are numeric:
SELECTkey_part1
,key_part2
FROMtbl_name
WHEREkey_part1
=val
; SELECT COUNT(*) FROMtbl_name
WHEREkey_part1
=val1
ANDkey_part2
=val2
; SELECTkey_part2
FROMtbl_name
GROUP BYkey_part1
;
The following queries use indexing to retrieve the rows in sorted order without a separate sorting pass:
SELECT ... FROMtbl_name
ORDER BYkey_part1
,key_part2
,... ; SELECT ... FROMtbl_name
ORDER BYkey_part1
DESC,key_part2
DESC, ... ;
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.
For BTREE
indexes, comparison of a key
part with a constant value is a range condition when using
the >
, <
,
>=
, <=
,
BETWEEN
, !=
, or
<>
operators, or LIKE
'
(where
pattern
''
does not start with a wildcard).
pattern
'
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:
A constant from the query string
A column of a const
or
system
table from the same join
The result of an uncorrelated subquery
Any expression composed entirely from subexpressions of the preceding types
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_col
IN (15,18,20); SELECT * FROM t1 WHEREkey_col
LIKE 'ab%' ORkey_col
BETWEEN 'bar' AND 'foo';
Note that some non-constant 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.
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_part1
key_part2
key_part3
NULL 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_part1
cmp
const1
ANDkey_part2
cmp
const2
AND ... ANDkey_partN
cmp
constN
;
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_part2
IS NULL ANDkey_part3
= 'foo'
For the definition of what is considered to be a constant, see Section 7.2.5.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_part2
IS NOT NULL
Section 7.2.5.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.
Note: If you have upgraded from a previous version of MySQL, you should be aware that this type of join optimization is first introduced in MySQL 5.0, and represents a significant change in behavior with regard to indexes. (Formerly, MySQL was able to use at most only one index for each referenced table.)
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_name
WHEREkey_part1
= 10 ORkey_part2
= 20; SELECT * FROMtbl_name
WHERE (key_part1
= 10 ORkey_part2
= 20) ANDnon_key_part
=30; SELECT * FROM t1, t2 WHERE (t1.key1
IN (1,2) OR t1.key2
LIKE 'value
%') AND t2.key1
=t1.some_col
; SELECT * FROM t1, t2 WHERE t1.key1
=1 AND (t2.key1
=t1.some_col
OR 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.
Note: The Index Merge optimization algorithm has the following known deficiencies:
If a range scan is possible on some key, an Index Merge is not considered. 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
that is not what you want, you can make the optimizer
consider Index Merge by using IGNORE
INDEX
or FORCE INDEX
. The
following queries are executed using Index Merge:
SELECT * FROM t1 FORCE INDEX(goodkey1,goodkey2) WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30; SELECT * FROM t1 IGNORE INDEX(badkey) WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30;
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:
(x
ANDy
) ORz
= (x
ORz
) AND (y
ORz
) (x
ORy
) ANDz
= (x
ANDz
) OR (y
ANDz
)
Index Merge is not applicable to fulltext 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
=const1
ANDkey_part2
=const2
... ANDkey_partN
=constN
Any range condition over a primary key of an
InnoDB
or BDB
table.
Examples:
SELECT * FROMinnodb_table
WHEREprimary_key
< 10 ANDkey_col1
=20; SELECT * FROMtbl_name
WHERE (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
or BDB
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
=const1
ANDkey_part2
=const2
... ANDkey_partN
=constN
Any range condition over a primary key of an
InnoDB
or BDB
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_table
WHERE (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_name
WHEREkey_col1
< 10 ORkey_col2
< 20; SELECT * FROMtbl_name
WHERE (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.
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_name
WHEREkey_col
IS NULL; SELECT * FROMtbl_name
WHEREkey_col
<=> NULL; SELECT * FROMtbl_name
WHEREkey_col
=const1
ORkey_col
=const2
ORkey_col
IS 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
AND
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);
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 12.10.3, “GROUP BY
with Hidden Fields”.
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 >const
GROUP 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.2.13, “GROUP BY
Optimization”.
When combining LIMIT
with
row_count
DISTINCT
, 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;
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 force a
specific table order, use STRAIGHT_JOIN
.
As of MySQL 5.0.1, the syntax for expressing joins allows nested
joins. The following discussion refers to the join syntax
described in Section 13.2.7.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 versions of MySQL prior to 5.0.1, parentheses in
table_references
were just omitted
and all join operations were grouped to the left. 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.0.)
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
The algorithm that converts outer join operations into inner joins was implemented in full measure, as it has been described here, in MySQL 5.0.1. MySQL 4.1 performs only some simple conversions.
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
=constant
ORDER BYkey_part2
; SELECT * FROM t1 ORDER BYkey_part1
DESC,key_part2
DESC; SELECT * FROM t1 WHEREkey_part1
=1 ORDER BYkey_part1
DESC,key_part2
DESC;
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 non-consecutive parts
of a key:
SELECT * FROM t1 WHEREkey2
=constant
ORDER BYkey_part2
;
You mix ASC
and DESC
:
SELECT * FROM t1 ORDER BYkey_part1
DESC,key_part2
ASC;
The key used to fetch the rows is not the same as the one
used in the ORDER BY
:
SELECT * FROM t1 WHEREkey2
=constant
ORDER BYkey1
;
You are joining many tables, and the columns in the
ORDER BY
are not all from the first
non-constant 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.
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.
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
”.
A filesort
optimization is used that records
not only the sort key value and row position, but the columns
required for the query as well. This avoids reading the rows
twice. The 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.
This algorithm represents a significant improvement over that used in some older versions of MySQL.
To avoid a slowdown, this 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.)
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.
Change tmpdir
to point to a dedicated
filesystem with large amounts of empty space. This option
accepts several paths that are used in round-robin fashion.
Paths should be separated by colon characters
(‘:
’) on Unix and semicolon
characters (‘;
’) on Windows,
NetWare, and OS/2. You can use this feature to spread the
load across several directories. Note:
The paths should be for directories in filesystems that are
located on different physical disks,
not different partitions on the same disk.
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;
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 via 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.
The most efficient way to process GROUP BY
is when the index is used to directly retrieve the group
fields. 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
includes the first
consecutive parts of the index. (If, instead of
GROUP BY
, the query has a
DISTINCT
clause, all distinct
attributes refer to the beginning of the index.)
The only aggregate functions used (if any) are
MIN()
and MAX()
, and
all of them refer to the same column.
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.
The EXPLAIN
output for such queries shows
Using index for group-by
in the
Extra
column.
The following queries fall into this category, assuming that
there is an index idx(c1,c2,c3)
on table
t1(c1,c2,c3,c4)
:
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 <const
GROUP BY c1, c2; SELECT MAX(c3), MIN(c3), c1, c2 FROM t1 WHERE c2 >const
GROUP BY c1, c2; SELECT c2 FROM t1 WHERE c1 <const
GROUP BY c1, c2; SELECT c1, c2 FROM t1 WHERE c3 =const
GROUP 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()
, for
example:
SELECT c1, SUM(c2) FROM t1 GROUP BY c1;
The fields in the GROUP BY
clause do
not refer to the beginning of the index, as shown here:
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, an example being:
SELECT c1,c3 FROM t1 GROUP BY c1, c2;
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 is
still 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. Notice that
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.
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 (assuming that there is an index
idx(c1,c2,c3)
on table
t1(c1,c2,c3,c4)
).
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;
In some cases, MySQL handles a query differently when you are
using LIMIT
and not using
row_count
HAVING
:
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_count
ORDER 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_count
DISTINCT
, 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_count
GROUP 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.2.4, “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 13.5.2.1, “tbl_name
ANALYZE 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.2.2, “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 non-empty table, you can tune the
bulk_insert_buffer_size
variable to make
data insertion even faster. See
Section 5.2.2, “Server System Variables”.
If you are inserting a lot of rows from different clients,
you can get higher speed by using the INSERT
DELAYED
statement. See
Section 13.2.4.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 table. See
Section 7.3.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 13.2.5, “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 14.1.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.
Note that LOAD DATA INFILE
performs the
preceding optimization automatically if the
MyISAM
table into which you insert data
is empty. The main difference 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 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_name
DISABLE KEYS; ALTER TABLEtbl_name
ENABLE KEYS;
To speed up INSERT
operations that are
performed with multiple statements for non-transactional
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. For example:
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
inserts or updates in a row. If you do very many inserts in
a row, you could do a LOCK TABLES
followed by an UNLOCK TABLES
once in a
while (each 1,000 rows or so) to allow other threads access
to the 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.5.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 13.5.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.5.2, “Tuning Server Parameters”.
To delete all rows from a table, TRUNCATE TABLE
if faster than
than tbl_name
DELETE FROM
. See
Section 13.2.9, “tbl_name
TRUNCATE
Syntax”.
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.5.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.
With MyISAM
tables that have no deleted
rows in the middle, you can insert rows at the end at the
same time that another query is 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. See Section 14.1, “The MyISAM
Storage Engine”.
To fix any compression issues that may have occurred with
ARCHIVE
tables, you can use
OPTIMIZE TABLE
. See
Section 14.8, “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 and reasonably unique, 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_name
WHEREhash_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 14, Storage Engines and Table Types.
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 14, Storage Engines and Table Types.
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_name
SETcount_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 non-redundant (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 Chapter 17, Stored Procedures and Functions, and Section 24.2, “Adding New Functions to MySQL”, for more information.
You can always gain something by caching queries or answers in your application and then performing many inserts or updates together. If your database system supports table locks (as do MySQL and Oracle), 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 5.14, “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.
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 to generate
unique values.
Use OPTIMIZE TABLE
once in a while to
avoid fragmentation with dynamic-format
MyISAM
tables. See
Section 14.1.3, “MyISAM
Table Storage Formats”.
Use MEMORY
(HEAP
)
tables when possible to get more speed. See
Section 14.4, “The MEMORY
(HEAP
) Storage Engine”.
MEMORY
tables are useful for non-critical
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 numerical 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 6, 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 uses table-level locking for MyISAM
and
MEMORY
tables, page-level locking for
BDB
tables, and row-level locking for
InnoDB
tables.
In many cases, you can make an educated guess about which locking type is best for an application, but generally it is difficult to say that a given lock type is better than another. Everything depends on the application and different parts of an application may require different lock types.
To decide whether you want to use a storage engine with
row-level locking, you should look at what your application does
and what mix of select and update statements it uses. For
example, most Web applications perform many selects, relatively
few deletes, updates based mainly on key values, and inserts
into a few specific tables. The base MySQL
MyISAM
setup is very well tuned for this.
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.
The table-locking method MySQL uses for WRITE
locks works 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.
The table-locking method MySQL uses for READ
locks works 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.
When a lock is released, the lock is made available to the
threads in the write lock queue and then to the threads in the
read lock queue. This means that if you have many updates for a
table, SELECT
statements wait until there are
no more updates.
You can analyze the table lock contention on your system by
checking the Table_locks_waited
and
Table_locks_immediate
status variables:
mysql> SHOW STATUS LIKE 'Table%';
+-----------------------+---------+
| Variable_name | Value |
+-----------------------+---------+
| Table_locks_immediate | 1151552 |
| Table_locks_waited | 15324 |
+-----------------------+---------+
If a MyISAM
table contains no free blocks in
the middle, rows always are 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 re-enabled automatically when all holes have
been filled with new data.)
If you want to perform many INSERT
and
SELECT
operations on a table when concurrent
inserts are not possible, you can insert rows in a temporary
table and update the real table with the rows from the temporary
table once in a while. This can be done with the following code:
mysql>LOCK TABLES real_table WRITE, insert_table WRITE;
mysql>INSERT INTO real_table SELECT * FROM insert_table;
mysql>TRUNCATE TABLE insert_table;
mysql>UNLOCK TABLES;
InnoDB
uses row locks and
BDB
uses page locks. For these two storage
engines, deadlocks are possible because they automatically
acquire locks during the processing of SQL statements, not at
the start of the transaction.
Advantages of row-level locking:
Fewer lock conflicts when accessing different rows in many threads.
Fewer changes for rollbacks.
Possible to lock a single row for a long time.
Disadvantages of row-level locking:
Requires more memory than page-level or table-level locks.
Slower than page-level or table-level locks when used on a large part of the table because you must acquire many more locks.
Definitely much 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.
Table locks are superior to page-level or row-level locks in the following cases:
Most statements for the table are reads.
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_name
SETcolumn
=value
WHEREunique_key_col
=key_value
; DELETE FROMtbl_name
WHEREunique_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 or page-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 page-level or 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
GET_LOCK()
and
RELEASE_LOCK()
in MySQL. These are
advisory locks, so they work only in well-behaved
applications. (See
Section 12.9.4, “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
BDB
.
For InnoDB
and BDB
tables,
MySQL uses only table locking if you explicitly lock the table
with LOCK TABLES
. For these storage engines,
we recommend that you not use LOCK TABLES
at
all, because InnoDB
uses automatic row-level
locking and BDB
uses page-level locking to
ensure transaction isolation.
For large tables, table locking is much better than row locking for most applications, but there are some pitfalls:
Table locking enables many threads to read from a table at the same time, but if a thread wants to write to a table, it must first get exclusive access. During the update, all other threads that want to access this particular table must wait until the update is done.
Table updates normally are considered to be more important
than table retrievals, so they are given higher priority.
This should ensure that updates to a table are not
“starved” even if there is heavy
SELECT
activity for the table.
Table locking causes problems in cases such as when a thread is waiting because the disk is full and free space needs to become available before the thread can proceed. In this case, all threads 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 client issues a SELECT
that takes a
long time to run.
Another client then issues an UPDATE
on
the same table. This client waits until the
SELECT
is finished.
Another client issues another SELECT
statement on the same table. Because
UPDATE
has higher priority than
SELECT
, this SELECT
waits for the UPDATE
to finish,
and 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
. 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.
You can specify that all updates issued in a specific
connection should be done with low priority by using the
SET LOW_PRIORITY_UPDATES=1
statement. See
Section 13.5.3, “SET
Syntax”.
You can give a specific INSERT
,
UPDATE
, or DELETE
statement lower priority with the
LOW_PRIORITY
attribute.
You can give a specific SELECT
statement
higher priority with the HIGH_PRIORITY
attribute. See Section 13.2.7, “SELECT
Syntax”.
You can 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 allows READ
locks after a certain
number of WRITE
locks.
If you have problems with INSERT
combined
with SELECT
, you might want to consider
switching to MyISAM
tables, which support
concurrent SELECT
and
INSERT
statements. (See
Section 7.3.3, “Concurrent Inserts”.)
If you mix inserts and deletes on the same table,
INSERT DELAYED
may be of great help. See
Section 13.2.4.2, “INSERT DELAYED
Syntax”.
If you have problems with mixed SELECT
and DELETE
statements, the
LIMIT
option to DELETE
may help. See Section 13.2.1, “DELETE
Syntax”.
Using SQL_BUFFER_RESULT
with
SELECT
statements can help to make the
duration of table locks shorter. See
Section 13.2.7, “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
or
BDB
tables. See Section 14.2, “The InnoDB
Storage Engine”,
and Section 14.5, “The BDB
(BerkeleyDB
) Storage Engine”.
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 table.
Under circumstances where concurrent inserts can be used, there
is seldom any need to use the DELAYED
modifier for INSERT
statements. See
Section 13.2.4.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.
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 threads can
retrieve data from the table while LOAD DATA
is executing. Using this option affects the performance of
LOAD DATA
a bit, even if no other thread is
using the table at the same time.
MyISAM
Key CacheMyISAM
Index Statistics CollectionMySQL keeps row data and index data in separate files. Many (almost all) other database systems mix row and index data in the same file. We believe that the MySQL choice is better for a very wide range of modern systems.
Another way to store the row data is to keep the information for each column in a separate area (examples are SDBM and Focus). This causes a performance hit for every query that accesses more than one column. Because this degenerates so quickly when more than one column is accessed, we believe that this model is not good for general-purpose databases.
The more common case is that the index and data are stored together (as in Oracle/Sybase, et al). In this case, you find the row information at the leaf page of the index. The good thing with this layout is that it, in many cases, depending on how well the index is cached, saves a disk read. The bad things with this layout are:
Table scanning is much slower because you have to read through the indexes to get at the data.
You cannot use only the index table to retrieve data for a query.
You use more space because you must duplicate indexes from the nodes (you cannot store the row in the nodes).
Deletes degenerate the table over time (because indexes in nodes are usually not updated on delete).
It is more difficult to cache only the index data.
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 14, Storage Engines and Table Types.
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 14.1.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
.
Starting with MySQL 5.0.3, InnoDB
tables
use a more compact storage format. In earlier versions of
MySQL, 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 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, you should use the column with more duplicates first 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's better to
index only this prefix, using MySQL's support for creating
an index on the leftmost part of the column (see
Section 13.1.4, “CREATE INDEX
Syntax”). Shorter indexes are faster,
not only because they require less disk space, but because
they give also you more hits in the index cache, and thus
fewer disk seeks. See Section 7.5.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.
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 14, Storage Engines and Table Types. 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 partial (column prefix) indexing is
not supported. For details, see
Section 12.7, “Full-Text Search Functions”.
You can also create indexes on spatial data types. Currently,
only MyISAM
supports R-tree indexes on
spatial types. As of MySQL 5.0.16, 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 15 columns. For certain data types, you can index a prefix of the column (see Section 7.4.3, “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.4.5, “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 13.1.4, “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.
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
=
constant
key_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_name
WHEREkey_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_part2
DESC
, the key is
read in reverse order. See
Section 7.2.12, “ORDER 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_part3
FROMtbl_name
WHEREkey_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 tries 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 a partial index if the columns do not form a
leftmost prefix of the index. Suppose that you have the
SELECT
statements shown here:
SELECT * FROMtbl_name
WHERE col1=val1
; SELECT * FROMtbl_name
WHERE col1=val1
AND col2=val2
; SELECT * FROMtbl_name
WHERE col2=val2
; SELECT * FROMtbl_name
WHERE col2=val2
AND 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_name
WHEREkey_col
LIKE 'Patrick%'; SELECT * FROMtbl_name
WHEREkey_col
LIKE '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_name
WHEREkey_col
LIKE '%Patrick%'; SELECT * FROMtbl_name
WHEREkey_col
LIKEother_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 onindex1
but not onindex2
orindex3
*/ ... WHEREindex1
=1 ANDindex2
=2 ORindex1
=3 ANDindex3
=3;
These WHERE
clauses do
not use indexes:
/*index_part1
is 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.)
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 filesystem 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:
Access to the key cache no longer is serialized among threads. Multiple threads 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 filesystem 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 non-leaf 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 a special queue (LRU chain) of all used blocks. When a block is accessed, it is placed at the end of the queue. When blocks need to be replaced, blocks at the beginning of the queue are the least recently used and become the first candidates for eviction.
Threads can access key cache buffers simultaneously, subject to the following conditions:
A buffer that is not being updated can be accessed by multiple threads.
A buffer that is being updated causes threads that need to use it to wait until the update is complete.
Multiple threads 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 threads 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 13.5.5.1, “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.2.3.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, we recommend a strategy that uses 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 non-leaf 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.
CACHE INDEX
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 the 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 sub-chain and a warm sub-chain.
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 sub-chain. After a certain number of hits (accesses of the block), it is promoted to the hot sub-chain. 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 sub-chain is placed at the end
of the chain. The block then circulates within this sub-chain.
If the block stays at the beginning of the sub-chain for a
long enough time, it is demoted to the warm chain. 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 sub-chain not accessed within the
last
hits is to be moved to
the beginning of the warm sub-chain. It then becomes the first
candidate for eviction, because blocks for replacement always
are taken from the beginning of the warm sub-chain.
N
×
key_cache_age_threshold / 100
The midpoint insertion strategy allows 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 sub-chain 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 non-leaf nodes, it makes sense to preload the key cache with index blocks before starting to use it. Preloading allows 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 non-leaf nodes of the index to be preloaded.
Thus, the statement shown preloads all index blocks from
t1
, but only blocks for the non-leaf 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.
Currently, you cannot control the size of the index blocks in
a table. This size is set by the server when the
.MYI
index file is created, depending on
the size of the keys in the indexes present in the table
definition. In most cases, it is set equal to the I/O buffer
size.
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 filesystem caching. Filesystem 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 filesystem caching for the indexes ceases.
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_name
ONtbl_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
<=>
N
N
.
However, for a join based on the =
operator,
NULL
is different from
non-NULL
values:
is not true when
expr1
=
expr2
expr1
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
=
expr
expr
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 allow 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 two 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.
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:
Set myisam_stats_method
, and then issue a
CHECK TABLE
statement
Execute myisamchk
--stats_method=method_name
--analyze
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.
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 threads having different states on
the same table, the table is opened independently by each
concurrent thread. 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 threads.)
The table_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 allow 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_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
N
N
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_cache
setting. If
table_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 A.2.17, “File Not Found”.
The cache of open tables is kept at a level of
table_cache
entries. The default value is 64;
this can be changed with the --table_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_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 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 13.2.3, “tbl_name
CLOSEHANDLER
Syntax”.
You can determine whether your table cache is too small by
checking the mysqld status variable
Opened_tables
:
mysql> SHOW STATUS LIKE 'Opened_tables';
+---------------+-------+
| Variable_name | Value |
+---------------+-------+
| Opened_tables | 2741 |
+---------------+-------+
If the value is very large, even when you have not issued many
FLUSH TABLES
statements, you should increase
the table cache size. See
Section 5.2.2, “Server System Variables”, and
Section 5.2.4, “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 making
the table cache larger.
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 filesystem. Other filesystems 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:
back_log 50 binlog_cache_size 32768 bulk_insert_buffer_size 8388608 connect_timeout 5 date_format (No default value) datetime_format (No default value) default_week_format 0 delayed_insert_limit 100 delayed_insert_timeout 300 delayed_queue_size 1000 expire_logs_days 0 flush_time 1800 ft_max_word_len 84 ft_min_word_len 4 ft_query_expansion_limit 20 ft_stopword_file (No default value) group_concat_max_len 1024 innodb_additional_mem_pool_size 1048576 innodb_autoextend_increment 8 innodb_buffer_pool_awe_mem_mb 0 innodb_buffer_pool_size 8388608 innodb_concurrency_tickets 500 innodb_file_io_threads 4 innodb_force_recovery 0 innodb_lock_wait_timeout 50 innodb_log_buffer_size 1048576 innodb_log_file_size 5242880 innodb_log_files_in_group 2 innodb_mirrored_log_groups 1 innodb_open_files 300 innodb_sync_spin_loops 20 innodb_thread_concurrency 8 innodb_thread_sleep_delay 10000 interactive_timeout 28800 join_buffer_size 131072 key_buffer_size 8388600 key_cache_age_threshold 300 key_cache_block_size 1024 key_cache_division_limit 100 long_query_time 10 lower_case_table_names 1 max_allowed_packet 1048576 max_binlog_cache_size 4294967295 max_binlog_size 1073741824 max_connect_errors 10 max_connections 100 max_delayed_threads 20 max_error_count 64 max_heap_table_size 16777216 max_join_size 4294967295 max_length_for_sort_data 1024 max_relay_log_size 0 max_seeks_for_key 4294967295 max_sort_length 1024 max_tmp_tables 32 max_user_connections 0 max_write_lock_count 4294967295 multi_range_count 256 myisam_block_size 1024 myisam_data_pointer_size 6 myisam_max_extra_sort_file_size 2147483648 myisam_max_sort_file_size 2147483647 myisam_repair_threads 1 myisam_sort_buffer_size 8388608 net_buffer_length 16384 net_read_timeout 30 net_retry_count 10 net_write_timeout 60 open_files_limit 0 optimizer_prune_level 1 optimizer_search_depth 62 preload_buffer_size 32768 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 2048 read_buffer_size 131072 read_only FALSE read_rnd_buffer_size 262144 div_precision_increment 4 record_buffer 131072 relay_log_purge TRUE relay_log_space_limit 0 slave_compressed_protocol FALSE slave_net_timeout 3600 slave_transaction_retries 10 slow_launch_time 2 sort_buffer_size 2097144 sync-binlog 0 sync-frm TRUE sync-replication 0 sync-replication-slave-id 0 sync-replication-timeout 10 table_cache 64 thread_cache_size 0 thread_concurrency 10 thread_stack 196608 time_format (No default value) tmp_table_size 33554432 transaction_alloc_block_size 8192 transaction_prealloc_size 4096 updatable_views_with_limit 1 wait_timeout 28800
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 variables
shell>mysqladmin extended-status
For a full description of all system and status variables, see Section 5.2.2, “Server System Variables”, and Section 5.2.4, “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_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_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_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.
When you have installed MySQL, the
support-files
directory contains some
different my.cnf
sample files:
my-huge.cnf
,
my-large.cnf
,
my-medium.cnf
, and
my-small.cnf
. You can use these as a basis
for optimizing your system. (On Windows, look in the MySQL
installation directory.)
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 14.2.11, “InnoDB
Performance Tuning Tips”.
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–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.
MySQL 5.0.1 introduces a more flexible method for query optimization that allows 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 via 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.
Most of the following tests were performed on Linux with the MySQL benchmarks, but they should give some indication for other operating systems and workloads.
You obtain the fastest executables when you link with
-static
.
On Linux, it is best to compile the server with
pgcc and -O3
. You need about
200MB memory to compile sql_yacc.cc
with
these options, because gcc or
pgcc needs a great deal of memory to make all
functions inline. You should also set CXX=gcc
when configuring MySQL to avoid inclusion of the
libstdc++
library, which is not needed. Note
that with some versions of pgcc, the
resulting binary runs only on true Pentium processors, even if
you use the compiler option indicating that you want the
resulting code to work on all x586-type processors (such as
AMD).
By using a better compiler and compilation options, you can obtain a 10–30% speed increase in applications. This is particularly important if you compile the MySQL server yourself.
When we tested both the Cygnus CodeFusion and Fujitsu compilers, neither was sufficiently bug-free to allow MySQL to be compiled with optimizations enabled.
The standard MySQL binary distributions are compiled with
support for all character sets. When you compile MySQL yourself,
you should include support only for the character sets that you
are going to use. This is controlled by the
--with-charset
option to
configure.
Here is a list of some measurements that we have made:
If you use pgcc and compile everything
with -O6
, the mysqld
server is 1% faster than with gcc 2.95.2.
If you link dynamically (without -static
),
the result is 13% slower on Linux. Note that you still can
use a dynamically linked MySQL library for your client
applications. It is the server that is most critical for
performance.
For a connection from a client to a server running on the
same host, if you connect using TCP/IP rather than a Unix
socket file, performance is 7.5% slower. (On Unix, if you
connect to the hostname localhost
, MySQL
uses a socket file by default.)
For TCP/IP connections from a client to a server, connecting to a remote server on another host is 8–11% slower than connecting to a server on the same host, even for connections over 100Mb/s Ethernet.
When running our benchmark tests using secure connections (all data encrypted with internal SSL support) performance was 55% slower than with unencrypted connections.
If you compile with --with-debug=full
, most
queries are 20% slower. Some queries may take substantially
longer; for example, the MySQL benchmarks run 35% slower. If
you use --with-debug
(without
=full
), the speed decrease is only 15%.
For a version of mysqld that has been
compiled with --with-debug=full
, you can
disable memory checking at runtime by starting it with the
--skip-safemalloc
option. The execution
speed should then be close to that obtained when configuring
with --with-debug
.
On a Sun UltraSPARC-IIe, a server compiled with Forte 5.0 is 4% faster than one compiled with gcc 3.2.
On a Sun UltraSPARC-IIe, a server compiled with Forte 5.0 is 4% faster in 32-bit mode than in 64-bit mode.
Compiling with gcc 2.95.2 for UltraSPARC
with the -mcpu=v8 -Wa,-xarch=v8plusa
options gives 4% more performance.
On Solaris 2.5.1, MIT-pthreads is 8–12% slower than Solaris native threads on a single processor. With greater loads or more CPUs, the difference should be larger.
Compiling on Linux-x86 using gcc without
frame pointers (-fomit-frame-pointer
or
-fomit-frame-pointer -ffixed-ebp
) makes
mysqld 1–4% faster.
Binary MySQL distributions for Linux that are provided by MySQL AB used to be compiled with pgcc. We had to go back to regular gcc due to a bug in pgcc that would generate binaries that do not run on AMD. We will continue using gcc until that bug is resolved. In the meantime, if you have a non-AMD machine, you can build a faster binary by compiling with pgcc. The standard MySQL Linux binary is linked statically to make it faster and more portable.
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:
The key buffer (variable key_buffer_size
)
is shared by all threads; other buffers used by the server
are allocated as needed. See
Section 7.5.2, “Tuning Server Parameters”.
Each connection uses some thread-specific space:
A stack (default 192KB, variable
thread_stack
)
A connection buffer (variable
net_buffer_length
)
A result buffer (variable
net_buffer_length
)
The connection buffer and result buffer are dynamically
enlarged up to max_allowed_packet
when
needed. While a query is running, a copy of the current
query 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.
Only compressed MyISAM
tables are memory
mapped. This is because the 32-bit memory space of 4GB is
not large enough for most big tables. When systems with a
64-bit address space become more common, we may add general
support for memory mapping.
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 in
order 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 heap table exceeds the size of
tmp_table_size
, MySQL handles this
automatically by changing the in-memory heap table to a
disk-based MyISAM
table as necessary. You
can also increase the temporary table size by setting the
tmp_table_size
option to
mysqld, or by setting the SQL option
SQL_BIG_TABLES
in the client program. See
Section 13.5.3, “SET
Syntax”.
Most requests that perform a sort allocate a sort buffer and zero to two temporary files depending on the result set size. See Section A.4.4, “Where MySQL Stores Temporary Files”.
Almost all parsing and calculating is done in a local memory
store. 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. This is
done with malloc()
and
free()
.
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
N
N
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. By default, the cache has 64 entries. 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.4.8, “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.
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. You can verify
this by checking 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.
When a new client connects to mysqld, mysqld spawns a new thread to handle the request. This thread first checks whether the hostname is in the hostname cache. If not, the thread attempts to resolve the hostname:
If the operating system supports the thread-safe
gethostbyaddr_r()
and
gethostbyname_r()
calls, the thread uses
them to perform hostname 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 hostnames that are not in the
hostname cache until the first thread unlocks the mutex.
You can disable DNS hostname 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 hostname cache by starting the server with
the --skip-host-cache
option. To clear the
hostname 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.
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.6.1, “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.5, “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, filesystem corruption may result, so back up
everything before experimenting!
You can also set the parameters for the filesystem 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 filesystems with the -o noatime
option. That skips updates to the last access time in inodes
on the filesystem, which avoids some disk seeks.
On many operating systems, you can set a filesystem 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/test
shell>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>cd
shell>/path/to/datadir
ln -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 13.1.5, “CREATE TABLE
Syntax”. Alternatively, symlinking
can be accomplished manually from the command line using
ln -s
if mysqld is
not running.
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.
Note: 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 allow system users to have
write access to MySQL database directories.
If you rename a table with ALTER TABLE ...
RENAME
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
to
move a table to another database, the table is moved to
the other database directory. The old symlinks and the
files to which they pointed are deleted. In other words,
the new table is not symlinked.
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>cd
shell>/path/to/datadir
/db1ln -s tbl1.frm tbl2.frm
shell>ln -s tbl1.MYD tbl2.MYD
shell>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 pathname D:\data\foo\
.
After this, all tables created in the database
foo
are created in
D:\data\foo
. Note that the
symbolic link is not used if a directory with the same name as
the database exists in the MySQL data directory.