Optimization is a complicated task because it ultimately requires understanding of the whole system. While it may be possible to perform some local optimizations with small knowledge of your system or application, the more optimal you want your system to become the more you will have to know about it.
This chapter tries to explain and give some examples of different ways to optimize MySQL. Remember, however, that there are always some (increasingly harder) additional ways to make the system even faster.
The most important factor in making a system fast is the basic design. You also need to know what kinds of things your system will be doing, and what your bottlenecks are.
The most common bottlenecks are:
When using the MyISAM storage engine, MySQL uses extremely fast table locking (multiple readers / single writers). The biggest problem with this table type occurs when you have a mix of a steady stream of updates and slow selects on the same table. If this is a problem with some tables, you can use another table type for these. See section 14 MySQL Table Types.
MySQL can work with both transactional and non-transactional tables. To be able to work smoothly with non-transactional tables (which can't roll back if something goes wrong), MySQL has the following rules:
NULL
in a
NOT NULL
column or a too big numerical value in a numerical
column, MySQL will instead of giving an error instead set the column to
the 'best possible value'. For numerical values this is 0, the smallest
possible values or the largest possible value. For strings this is
either the empty string or the longest possible string that can be in
the column.
NULL
For more information about this, see See section 1.8.6 How MySQL Deals with Constraints.
The above means that one should not use MySQL to check fields content, but one should do this in the application.
Because all SQL servers implement different parts of SQL, it takes work to write portable SQL applications. For very simple selects/inserts it is very easy, but the more you need the harder it gets. If you want an application that is fast with many databases it becomes even harder!
To make a complex application portable you need to choose a number of SQL servers that it should work with.
You can use the MySQL crash-me
program/web-page
http://www.mysql.com/information/crash-me.php to find functions,
types, and limits you can use with a selection of database
servers. Crash-me now tests far from everything possible, but it
is still comprehensive with about 450 things tested.
For example, you shouldn't have column names longer than 18 characters if you want to be able to use Informix or DB2.
Both the MySQL benchmarks and crash-me
programs are very
database-independent. By taking a look at how we have handled this, you
can get a feeling for what you have to do to write your application
database-independent. The benchmarks themselves can be found in the
`sql-bench' directory in the MySQL source
distribution. They are written in Perl with DBI database interface
(which solves the access part of the problem).
See http://www.mysql.com/information/benchmarks.html for the results from this benchmark.
As you can see in these results, all databases have some weak points. That is, they have different design compromises that lead to different behavior.
If you strive for database independence, you need to get a good feeling for each SQL server's bottlenecks. MySQL is very fast in retrieving and updating records, but will have a problem in mixing slow readers/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). Transaction databases in general are not very good at generating summary tables from log tables, as in this case row locking is almost useless.
To get your application really database-independent, you need to define an easy extendable interface through which you manipulate your data. As C++ is available on most systems, it makes sense to use a C++ classes interface to the databases.
If you use some specific feature for some database (like the
REPLACE
command in MySQL), you should code a method for
the other SQL servers to implement the same feature (but slower). With
MySQL you can use the /*! */
syntax to add
MySQL-specific keywords to a query. The code inside
/**/
will be treated as a comment (ignored) by most other SQL
servers.
If high performance is more important than exactness, as in some web applications, it is possibile 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 and set the expire timeout higher until things get back to normal.
In this case the table creation information should contain information of the initial size of the cache and how often the table should normally be refreshed.
During MySQL initial development, the features of MySQL were made to fit our largest customer. They handle data warehousing for a couple of the biggest retailers in Sweden.
From all stores, we get weekly summaries of all bonus card transactions, and we are expected to provide useful information for the store owners to help them find how their advertisement campaigns are affecting their customers.
The data is quite huge (about 7 million summary transactions per month), and we have data for 4-10 years that we need to present to the users. We got weekly requests from the customers that they want to get 'instant' access to new reports from this data.
We solved this by storing all information per month in compressed 'transaction' tables. We have a set of simple macros (script) that generates summary tables grouped by different criteria (product group, customer id, store ...) from the transactional tables. The reports are web pages that are dynamically generated by a small Perl script that parses a web page, executes the SQL statements in it, and inserts the results. We would have used PHP or mod_perl instead but they were not available at that time.
For graphical data we wrote a simple tool in C
that can produce
GIFs based on the result of an SQL query (with some processing of the
result). This is also dynamically executed from the Perl script that
parses the HTML files.
In most cases a new report can simply be done by copying an existing script and modifying the SQL query in it. In some cases, we will need to add more fields to an existing summary table or generate a new one, but this is also quite simple, as we keep all transactions tables on disk. (Currently we have at least 50G of transactions tables and 200G of other customer data.)
We also let our customers access the summary tables directly with ODBC so that the advanced users can themselves experiment with the data.
We haven't had any problems handling this with quite modest Sun Ultra SPARCstation (2x200 Mhz). We recently upgraded one of our servers to a 2 CPU 400 Mhz UltraSPARC, and we are now planning to start handling transactions on the product level, which would mean a ten-fold increase of data. We think we can keep up with this by just adding more disk to our systems.
We are also experimenting with Intel-Linux to be able to get more CPU power cheaper. Now that we have the binary portable database format (new in Version 3.23), we will start to use this for some parts of the application.
Our initial feelings are that Linux will perform much better on low-to-medium load and Solaris will perform better when you start to get a high load because of extreme disk IO, but we don't yet have anything conclusive about this. After some discussion with a Linux kernel developer, this might be a side effect of Linux allocating so many resources to the batch job that the interactive performance gets very low. This makes the machine feel very slow and unresponsive while big batches are going. Hopefully this will be better handled in future Linux Kernels.
This section should contain a technical description of the MySQL
benchmark suite (and crash-me
), but that description is not
written yet. Currently, you can get a good idea of the benchmark by
looking at the code and results in the `sql-bench' directory in any
MySQL source distribution.
This benchmark suite is meant to be a benchmark that will tell any user what operations a given SQL implementation performs well or poorly.
Note that this benchmark is single-threaded, so it measures the minimum time for the operations performed. We plan to add a lot of multi-threaded tests to the benchmark suite in the future.
The following tables show some comparative benchmark results for several database servers when accessed through ODBC on a Windows NT 4.0 machine.
Reading 2000000 rows by index | Seconds | Seconds |
mysql | 367 | 249 |
mysql_odbc | 464 | |
db2_odbc | 1206 | |
informix_odbc | 121126 | |
ms-sql_odbc | 1634 | |
oracle_odbc | 20800 | |
solid_odbc | 877 | |
sybase_odbc | 17614 |
Inserting 350768 rows | Seconds | Seconds |
mysql | 381 | 206 |
mysql_odbc | 619 | |
db2_odbc | 3460 | |
informix_odbc | 2692 | |
ms-sql_odbc | 4012 | |
oracle_odbc | 11291 | |
solid_odbc | 1801 | |
sybase_odbc | 4802 |
For the preceding tests, MySQL was run with an index cache size of 8M.
We have gathered some more benchmark results at http://www.mysql.com/information/benchmarks.html.
Note that Oracle is not included because they asked to be removed. All Oracle benchmarks have to be passed by Oracle! We believe that makes Oracle benchmarks very biased because the above benchmarks are supposed to show what a standard installation can do for a single client.
To use the benchmark suite, the following requirements must be satisified:
The benchmark suite is located in the `sql-bench' directory of MySQL
source distributions.
To run the benchmark tests, change location into that directory and execute
the run-all-tests
script:
shell> cd sql-bench shell> perl run-all-tests --server=server_name
server_name
is one of supported servers. You can get a list of
all options and supported servers by invoking run-all-tests --help
.
crash-me
tries to determine what features a database supports and
what its capabilities and limitations are by actually running
queries. For example, it determines:
VARCHAR
column can be
We can find the result from crash-me
on a lot of different databases at
http://www.mysql.com/information/crash-me.php.
You should definitely benchmark your application and database to find out where the bottlenecks are. By fixing it (or by replacing the bottleneck with a ``dummy module'') you can then easily identify the next bottleneck (and so on). 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 an example of portable benchmark programs, look at 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 needs. By doing this, you can try different solutions to your problem and test which is really 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 (table scans are not good at high load) or problems with the operating system or libraries. Most of the time, these problems would be a lot 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 for this. It is available at http://www.mysql.com/Downloads/super-smack/super-smack-1.0.tar.gz. As the name suggests, it can bring your system to its knees if you ask it, so make sure to use it only on your development systems.
SELECT
Statements and Other QueriesFirst, one thing that affects all queries: The more complex permission system setup you have, the more overhead you get.
If you do not have any GRANT
statements done, MySQL will
optimize the permission checking somewhat. So if you have a very high
volume it may be worth the time to avoid grants. Otherwise, more
permission check results in a larger overhead.
If your problem is with some explicit MySQL function, you can always time this in the MySQL client:
mysql> SELECT BENCHMARK(1000000,1+1); +------------------------+ | BENCHMARK(1000000,1+1) | +------------------------+ | 0 | +------------------------+ 1 row in set (0.32 sec)
The above shows that MySQL can execute 1,000,000 +
expressions in 0.32 seconds on a PentiumII 400MHz
.
All MySQL functions should be very optimized, but there may be
some exceptions, and the BENCHMARK(loop_count,expression)
is a
great tool to find out if this is a problem with your query.
EXPLAIN
Syntax (Get Information About a SELECT
)EXPLAIN tbl_name or EXPLAIN SELECT select_options
EXPLAIN tbl_name
is a synonym for DESCRIBE tbl_name
or
SHOW COLUMNS FROM tbl_name
.
When you precede a SELECT
statement with the keyword EXPLAIN
,
MySQL explains how it would process the SELECT
, providing
information about how tables are joined and in which order.
With the help of EXPLAIN
, you can see when you must add indexes
to tables to get a faster SELECT
that uses indexes to find the
records.
You should frequently run ANALYZE TABLE
to update table statistics
such as cardinality of keys which can affect the choices the optimizer
makes. See section 13.5.2.1 ANALYZE TABLE
Syntax.
You can also see if the optimizer joins the tables in an optimal
order. To force the optimizer to use a specific join order for a
SELECT
statement, add a STRAIGHT_JOIN
clause.
For non-simple joins, EXPLAIN
returns a row of information for each
table used in the SELECT
statement. The tables are listed in the order
they would be read. MySQL resolves all joins using a single-sweep
multi-join method. This means that MySQL reads a row from the first
table, then finds a matching row in the second table, then in the third table
and so on. When all tables are processed, it 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.
In MySQL version 4.1 the EXPLAIN
output was changed to work better
with constructs like UNION
statements, subqueries and derived tables. Most
notable is the addition of two new columns: id
and select_type
.
Output from EXPLAIN
consists of the following columns:
id
SELECT
identifier, the sequential number of this SELECT
within the query.
select_type
SELECT
clause, which can be any of the following:
SIMPLE
SELECT
(not using UNION
or subqueries).
PRIMARY
SELECT
.
UNION
SELECT
statements in a UNION
.
DEPENDENT UNION
SELECT
statements in a UNION
, dependent on outer
subquery.
SUBQUERY
SELECT
in subquery.
DEPENDENT SUBQUERY
SELECT
, dependent on outer subquery.
DERIVED
SELECT
(subquery in FROM
clause).
table
type
system
const
join type.
const
const
tables are very fast as they are read only once!
const
is used when you compare all parts of a
PRIMARY
/UNIQUE
key with constants:
SELECT * FROM const_table WHERE primary_key=1; SELECT * FROM const_table WHERE primary_key_part1=1 AND primary_key_part2=2;
eq_ref
const
types. It is used when all parts of an index are used by
the join and the index is UNIQUE
or a PRIMARY KEY
.
eq_ref
can be used for indexed columns that is compared with the
=
operator. The compared item may be a constant or an expression
that uses columns from tables that are read before this table.
In the following examples, ref_table
will be able to use eq_ref
SELECT * FROM ref_table,other_table WHERE ref_table.key_column=other_table.column; SELECT * FROM ref_table,other_table WHERE ref_table.key_column_part1=other_table.column AND ref_table.key_column_part2=1;
ref
ref
is used if the join
uses only a leftmost prefix of the key, or if the key is not UNIQUE
or a PRIMARY KEY
(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 join type is good.
ref
can be used for indexed columns that is compared with the =
operator.
In the following examples, ref_table
will be able to use ref
.
SELECT * FROM ref_table WHERE key_column=expr; SELECT * FROM ref_table,other_table WHERE ref_table.key_column=other_table.column; SELECT * FROM ref_table,other_table WHERE ref_table.key_column_part1=other_table.column AND ref_table.key_column_part2=1;
ref_or_null
ref
, but with the addition that we will do an extra search for
rows with NULL
.
See section 7.2.6 How MySQL Optimizes IS NULL
.
SELECT * FROM ref_table WHERE key_column=expr OR key_column IS NULL;This join type optimization is new for MySQL 4.1.1 and is mostly used when resolving subqueries.
unique_subquery
ref
for some IN
subqueries of the following
form:
value IN (SELECT primary_key FROM single_table WHERE some_exp)
unique_subquery
is just an index lookup function that replaces the
subquery completely for better efficiency.
index_subquery
unique_subquery
, this type replaces IN
subqueries, but
it works for non-unique indexes:
value IN (SELECT key_field FROM single_table WHERE some_exp)
range
key
column indicates which index is used.
The key_len
contains the longest key part that was used.
The ref
column will be NULL
for this type.
range
can be used for when an key column is compared to a
constant with =
, <>
, >
, >=
, <
,
<=
, IS NULL
, <=>
, BETWEEN
and IN
.
SELECT * FROM range_table WHERE key_column = 10; SELECT * FROM range_table WHERE key_column BETWEEN 10 and 20; SELECT * FROM range_table WHERE key_column IN (10,20,30); SELECT * FROM range_table WHERE key_part1= 10 and key_part2 IN (10,20,30);
index
ALL
, except that only the index tree is
scanned. This is usually faster than ALL
, as the index file is usually
smaller than the datafile.
This can be used when the query only uses columns that are part of one index.
ALL
const
, and usually very bad in all other
cases. You normally can avoid ALL
by adding more indexes, so that
the row can be retrieved based on constant values or column values from
earlier tables.
possible_keys
possible_keys
column indicates which indexes MySQL
could use to find the rows in this table. Note that this column is
totally independent of the order of the tables. That means that some of
the keys in possible_keys
may 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 see if 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.2.2 ALTER TABLE
Syntax.
To see what indexes a table has, use SHOW INDEX FROM tbl_name
.
key
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 an key listed in the possible_keys
column, use
USE KEY/IGNORE KEY
in your query.
See section 13.1.7 SELECT
Syntax.
Also, running myisamchk --analyze
(see section 5.5.2.1 myisamchk
Invocation Syntax) or ANALYZE TABLE
(see section 13.5.2.1 ANALYZE TABLE
Syntax) on the table will help the
optimizer choose better indexes.
key_len
key_len
column indicates the length of the key that
MySQL decided to use. The length is NULL
if the
key
is NULL
. Note that this tells us how many parts of a
multi-part key MySQL will actually use.
ref
ref
column shows which columns or constants are used with the
key
to select rows from the table.
rows
rows
column indicates the number of rows MySQL
believes it must examine to execute the query.
Extra
Distinct
Not exists
LEFT JOIN
optimization on the
query and will 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 for this:
SELECT * FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.id IS NULL;Assume that
t2.id
is defined with NOT NULL
. In this case
MySQL will scan t1
and look up the rows in t2
through t1.id
. If MySQL finds a matching row in
t2
, it knows that t2.id
can never be NULL
, and will
not scan through the rest of the rows in t2
that has the same
id
. In other words, for each row in t1
, MySQL
only needs to do a single lookup in t2
, independent of how many
matching rows there are in t2
.
range checked for each record (index map: #)
Using filesort
join type
and storing the sort key + pointer to
the row for all rows that match the WHERE
. Then the keys are
sorted. Finally the rows are retrieved in sorted order.
Using index
Using temporary
ORDER BY
on a different column set than you did a GROUP
BY
on.
Using where
WHERE
clause will be used to restrict which rows will be
matched against the next table or sent to the client. If you don't have
this information and the table is of type ALL
or index
,
you may have something wrong in your query (if you don't intend to
fetch/examine all rows from the table).
Using filesort
and Using temporary
.
You can get a good indication of how good a join is by multiplying all values
in the rows
column of the EXPLAIN
output. This should tell you
roughly how many rows MySQL must examine to execute the query. This
number is also used when you restrict queries with the max_join_size
variable.
See section 7.5.2 Tuning Server Parameters.
The following example shows how a JOIN
can be optimized progressively
using the information provided by EXPLAIN
.
Suppose you have the SELECT
statement shown here, that you examine
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, assume that:
Table | Column | Column type |
tt | ActualPC | CHAR(10)
|
tt | AssignedPC | CHAR(10)
|
tt | ClientID | CHAR(10)
|
et | EMPLOYID | CHAR(15)
|
do | CUSTNMBR | CHAR(15)
|
Table | Index |
tt | ActualPC
|
tt | AssignedPC
|
tt | ClientID
|
et | EMPLOYID (primary key)
|
do | CUSTNMBR (primary key)
|
tt.ActualPC
values aren't 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,ClientID,ActualPC NULL NULL NULL 3872 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! This will take
quite a long time, as the product of the number of rows in each table must be
examined! For the case at hand, this 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't (yet) use indexes on columns
efficiently if they are declared differently. In this context,
VARCHAR
and CHAR
are the same unless they are declared as
different lengths. Because tt.ActualPC
is declared as CHAR(10)
and et.EMPLOYID
is declared as CHAR(15)
, 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,ClientID,ActualPC NULL NULL NULL 3872 Using where 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 now less by a factor of 74). This version is executed 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);
Now 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 where ClientID, ActualPC et_1 eq_ref PRIMARY PRIMARY 15 tt.AssignedPC 1 do eq_ref PRIMARY PRIMARY 15 tt.ClientID 1
This is almost as good as it can get.
The remaining problem is that, by default, MySQL assumes that values
in the tt.ActualPC
column are evenly distributed, and that isn't the
case for the tt
table. Fortunately, it is easy to tell MySQL
about this:
shell> myisamchk --analyze PATH_TO_MYSQL_DATABASE/tt shell> mysqladmin refresh
Now 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 where ClientID, 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. To optimize a
query, you should check if the numbers are even close to the truth. If not,
you may 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 the performance by counting disk seeks.
For small tables, you can usually find the row in 1 disk seek (as the
index is probably cached). For bigger tables, you can estimate that
(using B++ tree indexes) you will need: log(row_count) /
log(index_block_length / 3 * 2 / (index_length + data_pointer_length)) +
1
seeks to find a row.
In MySQL an index block is usually 1024 bytes and the data
pointer is usually 4 bytes. A 500,000 row table with an
index length of 3 (medium integer) gives you:
log(500,000)/log(1024/3*2/(3+4)) + 1
= 4 seeks.
As the above index would require about 500,000 * 7 * 3/2 = 5.2M, (assuming that the index buffers are filled to 2/3, which is typical) you will probably have much of the index in memory and you will probably only need 1-2 calls to read data from the OS to find the row.
For writes, however, you will need 4 seek requests (as above) to find where to place the new index and normally 2 seeks to update the index and write the row.
Note that the above doesn't mean that your application will slowly degenerate by log N! As long as everything is cached by the OS or SQL server things will only go marginally slower while the table gets bigger. After the data gets too big to be cached, things will start to go much slower until your applications is only bound by disk-seeks (which increase by log N). To avoid this, increase the index cache as the data grows. See section 7.5.2 Tuning Server Parameters.
SELECT
Queries
In general, when you want to make a slow SELECT ... WHERE
faster, the
first thing to check is whether you can add an index. See section 7.4.3 How MySQL Uses Indexes. All references between different tables
should usually be done with indexes. You can use the EXPLAIN
command
to determine which indexes are used for a SELECT
.
See section 7.2.1 EXPLAIN
Syntax (Get Information About a SELECT
).
Some general tips:
myisamchk
--analyze
on a table after it has been loaded with relevant 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 will use this to decide which index to
choose when you connect two tables with 'a non-constant expression'.
You can check the result from the analyze
run by doing SHOW
INDEX FROM table_name
and examining the Cardinality
column.
myisamchk
--sort-index --sort-records=1
(if you want to sort on index 1). If you
have a unique index from which you want to read all records in order
according to that index, this is a good way to make that faster. Note,
however, that this sorting isn't written optimally and will take a long
time for a large table!
WHERE
Clauses
The WHERE
optimizations are put in the SELECT
part here because
they are mostly used with SELECT
, but the same optimizations apply for
WHERE
in DELETE
and UPDATE
statements.
Also note that this section is incomplete. MySQL does many optimizations, and we have not had time to document them all.
Some of the optimizations performed by MySQL are listed here:
((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)
(a<b AND b=c) AND a=5 -> b>5 AND b=c AND a=5
(B>=5 AND B=5) OR (B=6 AND 5=5) OR (B=7 AND 5=6) -> B=5 OR B=6
COUNT(*)
on a single table without a WHERE
is retrieved
directly from the table information for MyISAM
and HEAP
tables.
This is also done for any NOT NULL
expression when used with only one
table.
SELECT
statements are impossible and returns no rows.
HAVING
is merged with WHERE
if you don't use GROUP BY
or group functions (COUNT()
, MIN()
...).
WHERE
is constructed to get a fast
WHERE
evaluation for each sub-join and also to skip records as
soon as possible.
WHERE
clause on a UNIQUE
index, or a PRIMARY KEY
, where all index parts are used with constant
expressions and the index parts are defined as NOT NULL
.
mysql> SELECT * FROM t WHERE primary_key=1; mysql> SELECT * FROM t1,t2 -> WHERE t1.primary_key=1 AND t2.primary_key=t1.id;
ORDER BY
and in GROUP
BY
come from the same table, then this table is preferred first when
joining.
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.
SQL_SMALL_RESULT
, MySQL will use an in-memory
temporary table.
HAVING
clause
are skipped.
Some examples of queries that are very fast:
mysql> SELECT COUNT(*) FROM tbl_name; mysql> SELECT MIN(key_part1),MAX(key_part1) FROM tbl_name; mysql> SELECT MAX(key_part2) FROM tbl_name -> WHERE key_part_1=constant; mysql> SELECT ... FROM tbl_name -> ORDER BY key_part1,key_part2,... LIMIT 10; mysql> SELECT ... FROM tbl_name -> ORDER BY key_part1 DESC,key_part2 DESC,... LIMIT 10;
The following queries are resolved using only the index tree (assuming the indexed columns are numeric):
mysql> SELECT key_part1,key_part2 FROM tbl_name WHERE key_part1=val; mysql> SELECT COUNT(*) FROM tbl_name -> WHERE key_part1=val1 AND key_part2=val2; mysql> SELECT key_part2 FROM tbl_name GROUP BY key_part1;
The following queries use indexing to retrieve the rows in sorted order without a separate sorting pass:
mysql> SELECT ... FROM tbl_name -> ORDER BY key_part1,key_part2,... ; mysql> SELECT ... FROM tbl_name -> ORDER BY key_part1 DESC,key_part2 DESC,... ;
OR
Clauses
The Merge Index
method is used to retrieve rows with several
ref
, ref_or_null
or range
scans and merge the
results into one.
This method is employed when the table condition is a disjunction of
conditions for which ref
, ref_or_null
, or range
could be used with different keys.
The key
column contains a list of used indexes. key_len
contains a list of the longest key parts of the used indexes.
Example:
SELECT * FROM table WHERE key1column = 10 OR key2column = 20; SELECT * FROM table WHERE (key1column = 10 OR key2column = 20) AND nonkeycolumn=30; SELECT * FROM t1,t2 WHERE (t1.key1 IN (1,2) OR t1.key2 LIKE 'value%') AND t2.key1=t1.somefield SELECT * FROM t1,t2 WHERE t1.key1=1 AND (t2.key1=t1.somefield OR t2.key2=t1.somefield2)
This ``join'' type optimization is new in MySQL 5.0.0, and represents a significant change in behaviour with regard to indexes since the old rule was that the server is only ever able to use at most one index for each referenced table.
IS NULL
MySQL can do the same optimization on column IS NULL
as it can do
with column = constant_value
. For example, MySQL can use
indexes and ranges to search for NULL
with IS NULL
.
SELECT * FROM table_name WHERE key_col IS NULL; SELECT * FROM table_name WHERE key_col <=> NULL; SELECT * FROM table_name WHERE key_col=# OR key_col=# OR key_col IS NULL
If you use column_name IS NULL
on a NOT NULL
in a WHERE
clause on table that is not used OUTER JOIN
that expression will be
optimized away.
MySQL 4.1.1 can additionally optimize the combination column =
expr AND column IS NULL
, an form that is common in resolved sub
queries. EXPLAIN
will show 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 key on t2 (a,b)):
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 after that a separate search after rows with NULL key.
Note that the optimization can only handle one IS NULL
level.
SELECT * FROM t1,t2 where (t1.a=t2.a AND t2.a IS NULL) OR (t1.b=t2.b AND t2.b IS NULL);
Int the above case MySQL will only use key lookups on the part
(t1.a=t2.a AND t2.a IS NULL)
and not be able to use the key part on
b
.
DISTINCT
DISTINCT
combined with ORDER BY
will in many cases
need a temporary table.
Note that as DISTINCT
may use GROUP BY
, you should be aware of
how MySQL works with in fields in ORDER BY
or HAVING
that
are not part of the selected fields. See section 12.7.3 GROUP BY
with Hidden Fields.
When combining LIMIT row_count
with DISTINCT
, MySQL will stop
as soon as it finds row_count
unique rows.
If you don't use columns from all used tables, MySQL will stop the scanning of the not used tables as soon as it has found the first match.
SELECT DISTINCT t1.a FROM t1,t2 where t1.a=t2.a;
In this case, assuming t1
is used before t2
(check with
EXPLAIN
), then MySQL will stop reading from t2
(for that
particular row in t1
) when the first row in t2
is found.
LEFT JOIN
and RIGHT JOIN
A LEFT JOIN B join_condition
in MySQL is implemented as follows:
B
is set to be dependent on table A
and all tables
that A
is dependent on.
A
is set to be dependent on all tables (except B
)
that are used in the LEFT JOIN
condition.
LEFT JOIN
condition is used to decide how we should retrieve rows
from table B. (In other words, any condition in the WHERE
clause
is not used).
WHERE
optimizations are done.
A
that matches the WHERE
clause, but there
wasn't any row in B
that matched the ON
condition,
then an extra B
row is generated with all columns set to NULL
.
LEFT JOIN
to find rows that don't exist in some
table and you have the following test: column_name IS NULL
in the
WHERE
part, where column_name is a column that is declared as
NOT NULL
, then MySQL will stop searching after more rows
(for a particular key combination) after it has found one row that
matches the LEFT JOIN
condition.
RIGHT JOIN
is implemented analogously to LEFT JOIN
.
The table read order forced by LEFT JOIN
and STRAIGHT JOIN
will help the join optimizer (which calculates in which order tables
should be joined) to do its work much more quickly, as there are fewer
table permutations to check.
Note that the above means that if you do a query of type:
SELECT * FROM a,b LEFT JOIN c ON (c.key=a.key) LEFT JOIN d (d.key=a.key) WHERE b.key=d.key
MySQL will do a full scan on b
as the LEFT JOIN
will force
it to be read before d
.
The fix in this case is to change the query to:
SELECT * FROM b,a LEFT JOIN c ON (c.key=a.key) LEFT JOIN d (d.key=a.key) WHERE b.key=d.key
Starting from 4.0.14, MySQL does the following LEFT JOIN
optimization:
If the WHERE
condition is always be false for the generated
NULL
row, the LEFT JOIN
is changed to a normal join.
For example, in the following query the WHERE
clause would be
false if t2.column would be NULL
so it's safe to convert to
a normal join.
SELECT * FROM t1 LEFT t2 ON (column) WHERE t2.column2 =5; -> SELECT * FROM t1,t2 WHERE t2.column2=5 AND t1.column=t2.column;
This can be made faster as MySQL can now use table t2
before
table t1
if this would result in a better query plan. To force a
specific table order, use STRAIGHT JOIN
.
ORDER BY
In some cases MySQL can uses index to satisfy an ORDER BY
or
GROUP BY
request without doing any extra sorting.
The index can also be used even if the ORDER BY
doesn't match the
index exactly, as long as all the unused index parts and all the extra
are ORDER BY
columns are constants in the WHERE
clause. The following queries will use the index to resolve the
ORDER BY
/ GROUP BY
part:
SELECT * FROM t1 ORDER BY key_part1,key_part2,... SELECT * FROM t1 WHERE key_part1=constant ORDER BY key_part2 SELECT * FROM t1 WHERE key_part1=constant GROUP BY key_part2 SELECT * FROM t1 ORDER BY key_part1 DESC,key_part2 DESC SELECT * FROM t1 WHERE key_part1=1 ORDER BY key_part1 DESC,key_part2 DESC
Some cases where MySQL can not use indexes to resolve the ORDER
BY
: (Note that MySQL will still use indexes to find the rows that
matches the WHERE
clause):
ORDER BY
on different keys:
SELECT * FROM t1 ORDER BY key1,key2
ORDER BY
using non-consecutive key parts.
SELECT * FROM t1 WHERE key2=constant ORDER BY key_part2
ASC
and DESC
.
SELECT * FROM t1 ORDER BY key_part1 DESC,key_part2 ASC
ORDER BY
:
SELECT * FROM t1 WHERE key2=constant ORDER BY key1
ORDER
BY
on are not all from the first not-const
table that is used to
retrieve rows (This is the first table in the EXPLAIN
output which
doesn't use a const
row fetch method).
ORDER BY
and GROUP BY
expressions.
HASH
index in HEAP
tables).
In the cases where MySQL have to sort the result, it uses the following algorithm:
WHERE
clause are skipped.
sort_buffer
).
MERGEBUFF
(7) regions to one block in
another temporary file. Repeat until all blocks from the first file
are in the second file.
MERGEBUFF2
(15)
blocks left.
read_rnd_buffer_size
) .
You can with EXPLAIN SELECT ... ORDER BY
check if MySQL can use
indexes to resolve the query. If you get Using filesort
in the
extra
column, then MySQL can't use indexes to resolve the
ORDER BY
. See section 7.2.1 EXPLAIN
Syntax (Get Information About a SELECT
).
If you want to have a higher ORDER BY
speed, you should first
see if you can get MySQL to use indexes instead of having to do an extra
sorting phase. If this is not possible, then you can do:
sort_buffer_size
variable.
read_rnd_buffer_size
variable.
tmpdir
to point to a dedicated disk with lots of empty space.
If you use MySQL 4.1 or later you can spread load between
several physical disks by setting tmpdir
to a list of paths
separated by colon :
(semicolon ;
on Windows). They
will be used in round-robin fashion.
Note: These paths should end up on different physical disks,
not different partitions of the same disk.
By default, MySQL sorts all GROUP BY x,y[,...]
queries as if you
specified ORDER BY x,y[,...]
in the query as well. If you include the
ORDER BY
clause explicitly, MySQL optimizes it away without any speed
penalty, though the sorting still occurs.
If a query includes GROUP BY
but you want to avoid the overhead
of sorting the result, you can supress sorting by specifying
ORDER BY NULL
:
INSERT INTO foo SELECT a,COUNT(*) FROM bar GROUP BY a ORDER BY NULL;
LIMIT
In some cases MySQL will handle the query differently when you are
using LIMIT row_count
and not using HAVING
:
LIMIT
, MySQL
will use indexes in some cases when it normally would prefer to do a
full table scan.
LIMIT row_count
with ORDER BY
, MySQL will end the
sorting as soon as it has found the first row_count
lines instead of sorting
the whole table.
LIMIT row_count
with DISTINCT
, MySQL will stop
as soon as it finds row_count
unique rows.
GROUP BY
can be resolved by reading the key in order
(or do a sort on the key) and then calculate summaries until the
key value changes. In this case LIMIT row_count
will not calculate any
unnecessary GROUP BY
values.
#
rows to the client, it
will abort the query (if you are not using SQL_CALC_FOUND_ROWS
).
LIMIT 0
will always quickly return an empty set. This is useful
to check the query and to get the column types of the result columns.
LIMIT row_count
is used to calculate how much space is required.
INSERT
QueriesThe time to insert a record consists approximately of:
where the numbers are somewhat proportional to the overall time. 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 (B-trees).
Some ways to speed up inserts:
INSERT
statements. This is much faster (many times
in some cases) than using separate INSERT
statements. If you are adding
data to non-empty table, you may tune up the bulk_insert_buffer_size
variable to make it even faster.
See section 13.5.3.4 SHOW VARIABLES
.
INSERT DELAYED
statement. See section 13.1.4 INSERT
Syntax.
MyISAM
tables you can insert rows at the same time
SELECT
statements are running if there are no deleted rows in the tables.
LOAD DATA INFILE
. This
is usually 20 times faster than using a lot of INSERT
statements.
See section 13.1.5 LOAD DATA INFILE
Syntax.
LOAD DATA INFILE
run even
faster when the table has many indexes. Use the following procedure:
CREATE TABLE
. For example, using
mysql
or Perl-DBI.
FLUSH TABLES
statement or the shell command mysqladmin
flush-tables
.
myisamchk --keys-used=0 -rq /path/to/db/tbl_name
. This will
remove all usage of all indexes from the table.
LOAD DATA INFILE
. This will not
update any indexes and will therefore be very fast.
myisampack
on it to make it smaller. See section 14.1.2.3 Compressed Table Characteristics.
myisamchk -r -q
/path/to/db/tbl_name
. This will create the index tree in memory before
writing it to disk, which is much faster because it avoids lots of disk
seeks. The resulting index tree is also perfectly balanced.
FLUSH TABLES
statement or the shell command mysqladmin
flush-tables
.
LOAD DATA INFILE
also does the above optimization if
you insert into an empty table; the main difference with the above
procedure is that you can let myisamchk
allocate much more temporary
memory for the index creation that you may want MySQL to allocate for
every index recreation.
Since MySQL 4.0 you can also use
ALTER TABLE tbl_name DISABLE KEYS
instead of
myisamchk --keys-used=0 -rq /path/to/db/tbl_name
and
ALTER TABLE tbl_name ENABLE KEYS
instead of
myisamchk -r -q /path/to/db/tbl_name
. This way you can also skip
FLUSH TABLES
steps.
mysql> LOCK TABLES a WRITE; mysql> INSERT INTO a VALUES (1,23),(2,34),(4,33); mysql> INSERT INTO a VALUES (8,26),(6,29); mysql> UNLOCK TABLES;The main speed difference is that 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 different INSERT
statements. Locking is not needed if you can insert all rows with a single
statement.
For transactional tables, you should use BEGIN/COMMIT
instead of
LOCK TABLES
to get a speedup.
Locking will also lower the total time of multi-connection tests, but the
maximum wait time for some threads will go up (because they wait for
locks). For example:
thread 1 does 1000 inserts thread 2, 3, and 4 does 1 insert thread 5 does 1000 insertsIf you don't use locking, 2, 3, and 4 will finish before 1 and 5. If you use locking, 2, 3, and 4 probably will not finish before 1 or 5, but the total time should be about 40% faster. As
INSERT
, UPDATE
, and DELETE
operations are very
fast in MySQL, you will obtain better overall performance by
adding locks around everything that does more than about 5 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
(about each 1000 rows) to allow other threads access to the table. This
would still result in a nice performance gain.
LOAD DATA INFILE
is much faster for loading data.
To get some more speed for both LOAD DATA INFILE
and
INSERT
, enlarge the key buffer. See section 7.5.2 Tuning Server Parameters.
UPDATE
Queries
Update queries are optimized as a SELECT
query with the additional
overhead of a write. The speed of the write is dependent on the size of
the data that is being updated and the number of indexes that are
updated. Indexes that are not changed will not be updated.
Also, another way to get fast updates is to delay updates and then do many updates in a row later. Doing many updates in a row is much quicker than doing one at a time if you lock the table.
Note that, with dynamic record format, updating a record to
a longer total length may split the record. So if you do this often,
it is very important to OPTIMIZE TABLE
sometimes.
See section 13.5.2.5 OPTIMIZE TABLE
Syntax.
DELETE
Queries
If you want to delete all rows in the table, you should use
TRUNCATE TABLE table_name
. See section 13.1.9 TRUNCATE
Syntax.
The time to delete a record is exactly proportional to the number of indexes. To delete records more quickly, you can increase the size of the index cache. See section 7.5.2 Tuning Server Parameters.
Unsorted tips for faster systems:
thread_cache_size
variable. See section 7.5.2 Tuning Server Parameters.
EXPLAIN
command. See section 7.2.1 EXPLAIN
Syntax (Get Information About a SELECT
).
SELECT
queries on MyISAM
tables that are
updated a lot. This is to avoid problems with table locking.
MyISAM
tables that have no deleted rows, you can insert rows
at the same time another query is reading from it. If this is important
for you, you should consider methods where you don't have to delete rows
or run OPTIMIZE TABLE
after you have deleted a lot of rows.
ALTER TABLE ... ORDER BY expr1,expr2...
if you mostly
retrieve rows in expr1,expr2...
order. By using this option after big
changes to the table, you may be able to get higher performance.
SELECT * FROM table_name WHERE hash=MD5(CONCAT(col1,col2))
AND col_1='constant' AND col_2='constant'
VARCHAR
or BLOB
columns. You will get dynamic row length as soon as you
are using a single VARCHAR
or BLOB
column. See section 14 MySQL Table Types.
UPDATE table SET count=count+1 WHERE index_column=constant
is very fast!
This is really important when you use MySQL table types like MyISAM and
ISAM that
only have table locking (multiple readers / single writers). This will
also give better performance with most databases, as the row locking
manager in this case will have less to do.
INSERT /*! DELAYED */
when you do not need to know when your
data is written. This speeds things up because many records can be written
with a single disk write.
INSERT /*! LOW_PRIORITY */
when you want your selects to be
more important.
SELECT /*! HIGH_PRIORITY */
to get selects that jump the
queue. That is, the select is done even if there is somebody waiting to
do a write.
INSERT
statement to store many rows with one
SQL command (many SQL servers supports this).
LOAD DATA INFILE
to load bigger amounts of data. This is
faster than normal inserts and will be even faster when myisamchk
is integrated in mysqld
.
AUTO_INCREMENT
columns to make unique values.
OPTIMIZE TABLE
once in a while to avoid fragmentation when
using a dynamic table format. See section 13.5.2.5 OPTIMIZE TABLE
Syntax.
HEAP
tables to get more speed when possible. See section 14 MySQL Table Types.
name
instead of
customer_name
in the customer table). To make your names portable
to other SQL servers you should keep them shorter than 18 characters.
MyISAM
directly, you could
get a speed increase of 2-5 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 the
above 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 types of optimization.
DELAY_KEY_WRITE=1
will make the updating of
indexes faster, as these are not logged to disk until the file is closed.
The downside is that you should run myisamchk
on these tables before
you start mysqld
to ensure that they are okay if something killed
mysqld
in the middle. As the key information can always be generated
from the data, you should not lose anything by using DELAY_KEY_WRITE
.
You can find a discussion about different locking methods in the appendix. See section D.4 Locking methods.
All locking in MySQL is deadlock-free, except for InnoDB
and
BDB
type tables.
This 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.
InnoDB
type tables automatically acquire their row locks and
BDB
type tables
their page locks during the processing of SQL statements, not at the start
of the transaction.
The locking method MySQL uses for WRITE
locks works as follows:
The locking method MySQL uses for READ
locks works as follows:
When a lock is released, the lock is made available to the threads in the write lock queue, then to the threads in the read lock queue.
This means that if you have many updates on a table, SELECT
statements will wait until there are no more updates.
To work around this for the case where you want to do many INSERT
and
SELECT
operations on a table, you can insert rows in a temporary
table and update the real table with the records 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;
You can use the LOW_PRIORITY
options with INSERT
,
UPDATE
or DELETE
or HIGH_PRIORITY
with
SELECT
if you want to prioritize retrieval in some specific
cases. You can also start mysqld
with --low-priority-updates
to get the same behavior.
Using SQL_BUFFER_RESULT
can also help making table locks shorter.
See section 13.1.7 SELECT
Syntax.
You could also 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.
The table locking code in MySQL is deadlock free.
MySQL uses table locking (instead of row locking or column
locking) on all table types, except InnoDB
and BDB
tables,
to achieve a very
high lock speed. For large tables, table locking is much better than
row locking for most applications, but there are some pitfalls.
For InnoDB
and BDB
tables, MySQL only uses table
locking if you explicitly lock the table with LOCK TABLES
.
For these table types we recommend you to not use
LOCK TABLES
at all, because InnoDB
uses automatic
row level locking and BDB
uses page level locking to
ensure transaction isolation.
As of MySQL Version 3.23.7 (3.23.25 for Windows), you can insert rows into
MyISAM
tables at the same time other threads are reading from the
table. Note that currently this only works if there are no holes resulting from
deleted rows in the table at the time the insert is made. When all holes
has been filled with new data, concurrent inserts will automatically be
enabled again.
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 will wait until the update is ready.
As updates on tables normally are considered to be more important than
SELECT
, all statements that update a table have higher priority
than statements that retrieve information from a table. This should
ensure that updates are not 'starved' because one issues a lot of heavy
queries against a specific table. (You can change this by using
LOW_PRIORITY
with the statement that does the update or
HIGH_PRIORITY
with the SELECT
statement.)
Starting from MySQL Version 3.23.7 one can use the
max_write_lock_count
variable to force MySQL to
temporary give all SELECT
statements, that wait for a table, a
higher priority after a specific number of inserts on a table.
Table locking is, however, not very good under the following scenario:
SELECT
that takes a long time to run.
UPDATE
on a used table. This client
will wait until the SELECT
is finished.
SELECT
statement on the same table. As
UPDATE
has higher priority than SELECT
, this SELECT
will wait for the UPDATE
to finish. It will also wait for the first
SELECT
to finish!
full disk
, in which case all
threads that wants to access the problem table will also be put in a waiting
state until more disk space is made available.
Some possible solutions to this problem are:
SELECT
statements to run faster. You may have to create
some summary tables to do this.
mysqld
with --low-priority-updates
. This will give
all statements that update (modify) a table lower priority than a SELECT
statement. In this case the last SELECT
statement in the previous
scenario would execute before the INSERT
statement.
INSERT
, UPDATE
, or DELETE
statement lower priority with the LOW_PRIORITY
attribute.
mysqld
with a low value for max_write_lock_count
to give
READ
locks after a certain number of WRITE
locks.
SET LOW_PRIORITY_UPDATES=1
.
See section 7.5.6 SET
Syntax.
SELECT
is very important with the
HIGH_PRIORITY
attribute. See section 13.1.7 SELECT
Syntax.
INSERT
combined with SELECT
,
switch to use the new MyISAM
tables as these support concurrent
SELECT
and INSERT
statements.
INSERT
and SELECT
statements, the
DELAYED
attribute to INSERT
will probably solve your problems.
See section 13.1.4 INSERT
Syntax.
SELECT
and DELETE
, the LIMIT
option to DELETE
may help. See section 13.1.1 DELETE
Syntax.
MySQL keeps row data and index data in separate files. Many (almost all) other databases 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 will cause 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 will 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:
One of the most basic optimization is to get your data (and indexes) to take as little space on the disk (and in memory) as possible. This can give huge improvements because disk reads are faster and normally less main memory will be used. Indexing also takes less resources if done on smaller columns.
MySQL supports a lot of different table types and row formats. Choosing the right table format may give you a big performance gain. See section 14 MySQL Table Types.
You can get better performance on a table and minimise storage space using the techniques listed here:
MEDIUMINT
is often better than INT
.
NOT NULL
if possible. It makes everything
faster and you save one bit per column. Note that if you really need
NULL
in your application you should definitely use it. Just avoid
having it on all columns by default.
VARCHAR
,
TEXT
, or BLOB
columns), a fixed-size record format is
used. This is faster but unfortunately may waste some space.
See section 14.1.2 MyISAM
Table Formats.
Indexes are used to find rows with specific column values fast. Without an index MySQL has to start with the first record and then read through the whole table to find the relevant rows. The bigger the table, the more this costs. If the table has an index for the columns in question, MySQL can quickly get a position to seek to in the middle of the datafile without having to look at all the data. If a table has 1000 rows, this is at least 100 times faster than reading sequentially. Note that if you need to access almost all 1000 rows, it is faster to read sequentially, because that minimises disk seeks.
All MySQL indexes (PRIMARY KEY
, UNIQUE
, and
INDEX
) are stored in B-trees. Strings are automatically prefix-
and end-space compressed. See section 13.2.4 CREATE INDEX
Syntax.
Indexes are used in the following ways:
WHERE
clause.
MAX()
or MIN()
value for a specific indexed
column. This is optimized by a preprocessor that checks if you are
using WHERE
key_part_# = constant on all key parts < N. In this case
MySQL will do a single key lookup and replace the MIN()
expression with a constant. If all expressions are replaced with
constants, the query will return at once:
SELECT MIN(key_part2),MAX(key_part2) FROM table_name where key_part1=10
ORDER BY
key_part_1,key_part_2
). The key is read in reverse order if all key
parts are followed by DESC
. See section 7.2.9 How MySQL Optimizes ORDER BY
.
SELECT key_part3 FROM table_name WHERE key_part1=1
Suppose 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 will find 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 can't use a partial index if the columns don't form a
leftmost prefix of the index. Suppose you have the SELECT
statements shown here:
mysql> SELECT * FROM tbl_name WHERE col1=val1; mysql> SELECT * FROM tbl_name WHERE col2=val2; mysql> SELECT * FROM tbl_name WHERE col2=val2 AND col3=val3;
If an index exists on (col1, col2, col3)
, only the first of the preceding
queries uses the index. The second and third queries do involve
indexed columns, but (col2)
and (col2, col3)
are not
leftmost prefixes of (col1, col2, col3)
.
MySQL also uses indexes for LIKE
comparisons if the argument
to LIKE
is a constant string that doesn't start with a wildcard
character. For example, the following SELECT
statements use indexes:
mysql> SELECT * FROM tbl_name WHERE key_col LIKE "Patrick%"; mysql> SELECT * FROM tbl_name WHERE key_col LIKE "Pat%_ck%";
In the first statement, only rows with "Patrick" <= key_col <
"Patricl"
are considered. In the second statement, only rows with
"Pat" <= key_col < "Pau"
are considered.
The following SELECT
statements will not use indexes:
mysql> SELECT * FROM tbl_name WHERE key_col LIKE "%Patrick%"; mysql> SELECT * FROM tbl_name WHERE key_col LIKE other_col;
In the first statement, the LIKE
value begins with a wildcard
character. In the second statement, the LIKE
value is not a
constant.
MySQL 4.0 does another optimization on LIKE
. If you use
... LIKE "%string%"
and string
is longer than 3 characters,
MySQL will use the Turbo Boyer-Moore
algorithm to initialize the
pattern for the string and then use this pattern to perform the search
quicker.
Searching using column_name IS NULL
will use indexes if
column_name
is an index.
MySQL normally uses the index that finds the smallest number of rows. An
index is used for columns that you compare with the following operators:
=
, >
, >=
, <
, <=
, BETWEEN
, or a
LIKE
with a pattern that begins with a non-wildcard prefix like
'something%'
.
Any index that doesn't 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:
... WHERE index_part1=1 AND index_part2=2 AND other_column=3 ... WHERE index=1 OR A=10 AND index=2 /* index = 1 OR index = 2 */ ... WHERE index_part1='hello' AND index_part_3=5 /* optimized like "index_part1='hello'" */ ... WHERE index1=1 AND index2=2 OR index1=3 AND index3=3; /* Can use index on index1 but not on index2 or index 3 */
These WHERE
clauses do not use indexes:
... WHERE index_part2=1 AND index_part3=2 /* index_part_1 is not used */ ... WHERE index=1 OR A=10 /* Index is not used in both AND parts */ ... WHERE index_part1=1 OR index_part2=10 /* No index spans all rows */
Note that sometime MySQL will not use an index, even if one
is available. One instance of this is when
use of the index would require MySQL to access more
than 30% of the rows in the table. (In this case a table scan is
probably much faster, as it will require many fewer seeks.)
However, if such a query uses LIMIT
to only retrieve
part of the rows, MySQL will use an index anyway, as it can
much more quickly find the few rows to return in the result.
All MySQL column 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 section 14 MySQL Table Types. All storage engines support a minimum of 16 indexes per table and a minimum total index length of 256 bytes.
For CHAR
and VARCHAR
columns, you can index a prefix of a
column. This is much faster and requires less disk space than indexing the
whole column. The syntax to use in the CREATE TABLE
statement to
index a column prefix looks like this:
INDEX index_name (col_name(length))
The example here creates an index for the first 10 characters of the
name
column:
mysql> CREATE TABLE test ( -> name CHAR(200) NOT NULL, -> INDEX index_name (name(10)));
For BLOB
and TEXT
columns, you must index a prefix of the
column. The prefix may be up to 255 bytes long.
In MySQL Version 3.23.23 or later, you can also create special
FULLTEXT
indexes. They are used for full-text search. Only the
MyISAM
table type supports FULLTEXT
indexes and only for
CHAR
, VARCHAR
, and TEXT
columns.
Indexing always happens over the entire column and partial (prefix) indexing
is not supported. See section 13.7 MySQL Full-text Search for details.
MySQL can create indexes on multiple columns. An index may
consist of up to 15 columns. (On CHAR
and VARCHAR
columns you
can also use a prefix of the column as a part of an index.)
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 don't specify values for the other columns.
Suppose a table has the following specification:
mysql> 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));
Then the index name
is an index over last_name
and
first_name
. The index can 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 will be used in the following queries:
mysql> SELECT * FROM test WHERE last_name="Widenius"; mysql> SELECT * FROM test WHERE last_name="Widenius" -> AND first_name="Michael"; mysql> SELECT * FROM test WHERE last_name="Widenius" -> AND (first_name="Michael" OR first_name="Monty"); mysql> SELECT * FROM test WHERE last_name="Widenius" -> AND first_name >="M" AND first_name < "N";
However, the name
index will not be used in the following
queries:
mysql> SELECT * FROM test WHERE first_name="Michael"; mysql> SELECT * FROM test WHERE last_name="Widenius" -> OR first_name="Michael";
For more information on the manner in which MySQL uses indexes to improve query performance, see section 7.4.3 How MySQL Uses Indexes.
To minimize disk I/O, the MyISAM storage engine employs a strategy that is used by many database management systems. It exploits a cache mechanism to keep the most frequently accessed table blocks in memory:
This section first describes the basic operation of the MyISAM
key
cache. Then it discusses changes made in MySQL 4.1 that improve key cache
performance and that allow you control over cache operation:
The key cache mechanism also is used for ISAM
tables, which use
B-tree indexes. However, the significance of this fact is on the wane.
ISAM
table use has been decreasing since MySQL 3.23 when
MyISAM
was introduced. MySQL 4.1 carries this trend further; the
ISAM
storage engine is disabled by default.
You can control the size of the key cache by means of 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).
If the key cache is not used, index files are accessed using only the native filesystem buffering provided by the operating system. (That is, 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 the 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, before being replaced, its contents are flushed to the table index from which it came.
Usually the server follows a LRU (Least Recently Used) strategy: When choosing a block for replacement, it selects the least recently used index block. To be able to make such a choice easy, 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.
Prior to MySQL 4.1, access to the key cache is serialized: No two threads can access key cache buffers simultaneously. The server processes a request for an index block only after it has finished processing the previous request. As a result, a request for an index block not present in any key cache buffer blocks access by other threads while a buffer is being updated to contain the requested index block.
Starting from version 4.1.0, the server supports shared access to the key cache:
Shared access to the key cache allows 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 4.1.1 offers the feature of multiple key caches. This allows you to assign different table indexes to different key caches.
When there may be 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.
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 | +---------+--------------------+----------+----------+
Note: If the server has been built with the ISAM
storage
engine enabled, ISAM
tables use the key cache mechanism. However,
ISAM
indexes use only the default key cache and cannot be reassigned to
a different cache.
The key cache referred to in a CACHE INDEX
statement can be created
by setting its size with a parameter setting statement or in the server
parameter settings. 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;
See section 10.4.2 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 start-up. When a key cache is destroyed, all indexes assigned to it become assigned to the default key cache again.
For a busy server, we recommend a strategy that uses three key caches:
One reason the use of three key caches be beneficial is that access to one key cache structure does not block access to the others. Queries that access tables assigned to one cache do not compete with queries that access tables assigned to another cache. Performance gains occur for other reasons as well:
By default, the key cache management system of MySQL 4.1 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. The
key_cache_division_limit
value is a parameter and can be set per key
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. In the future, we will allow the hit count to depend on the B-tree level of the node corresponding to an index block: Fewer hits will be required for promotion of an index block if it contains a non-leaf node from the upper levels of the index B-tree than if it contains a leaf node.
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 key_cache_age_threshold
variable of the key cache.
This variable prescribes that, for a key cache containing N
blocks,
the block at the beginning of the hot sub-chain not accessed within the last
N*key_cache_age_threshold/100
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.
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
variable set to its default value 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 will be 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, then 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 still will be placed into the key cache as needed by queries. In this case, however, although the blocks will stay in the cache as there are enough buffers for all of them, they will be fetched from disk in a random order, 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,
this statement 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.
MySQL 4.1 introduces a new key_cache_block_size
variable on
a per-key cache basis. This variable specifies the size of the block
buffers for a key cache.
This variable is introduced to allow tuning the performance of I/O operations for index files.
The best performance for I/O operations is achieved when the size of read buffers are equal to the size of the native operating system I/O buffers. But setting the size of key nodes equal to the size of 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. In the
future this will be changed and then key_cache_block_size
variable
will be fully employed.
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 currrent 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 recreating the cache. Restructuring does not occur if you set 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 will execute, a slowdown can be anticipated. Once the cache has been restructured, it becomes available again for caching indexes assigned to it. The use of filesystem caching for the indexes ceases.
When you run mysqladmin status
, you'll 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 6 tables.
MySQL is multi-threaded, so there may be many clients issuing queries for a
given
simultaneously. To minimise the problem with two client threads having
different states on the same file, the table is opened independently by
each concurrent thread. This takes some memory but will normally increase
performance. With ISAM
and MyISAM
tables,
one extra file descriptor is required for the datafile for each client that
has the table open. With these table types, the index
file descriptor is shared between all threads.
You can read more about this topic in the next section. See section 7.4.8 How MySQL Opens and Closes Tables.
The table_cache
, max_connections
, and max_tmp_tables
server 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. You can increase the open-files limit on many
operating systems, though 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 * n
, where n
is the maximum number of tables
in a join. You also need to 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 for MySQL with
the --open-files-limit=#
startup option. See section A.2.17 File Not Found.
The cache of open tables will be kept at a level of table_cache
entries. The default value is 64; this can be changed with the -O
table_cache=#
option to mysqld
). Note that MySQL may
temporarily open even more tables to be able to execute queries.
A not used table is closed and removed from the table cache under the following circumstances:
table_cache
entries and
a thread is no longer using a table.
mysqladmin refresh
or
mysqladmin flush-tables
.
FLUSH TABLES
statement.
When the table cache fills up, the server uses the following procedure to locate a cache entry to use:
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). The first open of any table takes two file descriptors; each additional use of the table takes only one file descriptor. The extra descriptor for the first open is used for the index file; this descriptor is shared among all threads.
If you are opening a table with the HANDLER table_name OPEN
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 HANDLER table_name CLOSE
or the thread dies.
See section 13.1.3 HANDLER
Syntax. When this happens, the table is put
back in the table cache (if the cache isn't full).
You can check if your table cache is too small by checking the mysqld
variable Opened_tables
. If this is quite big, even if you
haven't done a lot of FLUSH TABLES
, you should increase your table
cache size. See section 13.5.3.3 SHOW STATUS
.
If you have many files in a directory, open, close, and create operations will
be slow. If you execute SELECT
statements on many different tables,
there will be 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 the system level factors, because some of these decisions must be made very early. In other cases, a quick look at this section may suffice because it not that important for the big gains. However, it is always nice to have a feeling about how much one could gain by changing things at this level.
The default operating system to use is really important! To get the best use of multiple-CPU machines, you should use Solaris (because its threads implementation works really well) or Linux (because the 2.2 kernel has really good SMP support). Also, older Linux kernels have a 2G file-size limit by default. If you have such a kernel and a desperate need for files larger than 2G, you should get the LFS (large file system) patch for the ext2 filesystem. Other filesystems such as ReiserFS and XFS do not have this 2G limitation.
Because we have not run MySQL in production on that many platforms, we advise you to test your intended platform before choosing it, if possible.
--skip-external-locking
MySQL option to avoid external
locking. Note that this will not impact MySQL's functionality as long as you
only run one server. Just remember to take down the server (or lock and flush
the relevant tables) before you run myisamchk
. On some systems this
option is mandatory, because the external locking does not work in any case.
The --skip-external-locking
option is on by default as of MySQL 4.0.
Before that, it is on by default when compiling with
MIT-pthreads, because flock()
isn't fully supported by
MIT-pthreads on all platforms. It's also on default for Linux
as Linux file locking are not yet safe.
The only case when you can't use --skip-external-locking
is if you run
multiple MySQL servers (not clients) on the same data,
or if you run myisamchk
on the table without telling the server
to flush and lock the tables first.
You can still use LOCK TABLES
/UNLOCK TABLES
even if you
are using --skip-external-locking
.
You can determine the default buffer sizes used by the mysqld
server
with this command:
shell> mysqld --help
This command produces a list of all mysqld
options and configurable
variables. The output includes the default variable values and looks something
like this:
back_log current value: 5 bdb_cache_size current value: 1048540 binlog_cache_size current value: 32768 connect_timeout current value: 5 delayed_insert_timeout current value: 300 delayed_insert_limit current value: 100 delayed_queue_size current value: 1000 flush_time current value: 0 interactive_timeout current value: 28800 join_buffer_size current value: 131072 key_buffer_size current value: 1048540 lower_case_table_names current value: 0 long_query_time current value: 10 max_allowed_packet current value: 1048576 max_binlog_cache_size current value: 4294967295 max_connections current value: 100 max_connect_errors current value: 10 max_delayed_threads current value: 20 max_heap_table_size current value: 16777216 max_join_size current value: 4294967295 max_sort_length current value: 1024 max_tmp_tables current value: 32 max_write_lock_count current value: 4294967295 myisam_sort_buffer_size current value: 8388608 net_buffer_length current value: 16384 net_retry_count current value: 10 net_read_timeout current value: 30 net_write_timeout current value: 60 read_buffer_size current value: 131072 read_rnd_buffer_size current value: 262144 slow_launch_time current value: 2 sort_buffer current value: 2097116 table_cache current value: 64 thread_concurrency current value: 10 tmp_table_size current value: 1048576 thread_stack current value: 131072 wait_timeout current value: 28800
If there is a mysqld
server currently running, you can see what
values it actually is using for the variables by issuing this statement:
mysql> SHOW VARIABLES;
You can also see some statistics and status indicators for a running server by issuing this statement:
mysql> SHOW STATUS;
You can find a full description for all variables in the SHOW VARIABLES
section in this manual. See section 13.5.3.4 SHOW VARIABLES
.
For information about status variables, see
section 13.5.3.3 SHOW STATUS
.
Server variable and status information also can be obtained using
mysqladmin
:
shell> mysqladmin variables shell> mysqladmin extended-status
MySQL uses algorithms that are very scalable, so you can usually run with very little memory. However, if you give MySQL more memory, normally you will also get better performance.
When tuning a MySQL server, the two most important variables to use
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. The examples use the mysqld_safe
script and
use --name=value
syntax to set the variable name
to the value
value
. This syntax is available as of MySQL 4.0. For older versions
of MySQL, take the following differences into account:
safe_mysqld
rather than mysqld_safe
.
--set-variable=name=value
or -O name=value
syntax.
_size
, you may need to specify them
without _size
. For example, the old name for sort_buffer_size
is
sort_buffer
. The old name for read_buffer_size
is
record_buffer
. To see which variables your version of the server
recognizes, use mysqld --help
.
If you have at least 256M 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 128M of memory and only a few tables, but you still do a lot of sorting, you can use something like:
shell> mysqld_safe --key_buffer_size=16M --sort_buffer_size=1M
If you have 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 -O net_buffer_length=1K &
If you are doing a GROUP BY
or ORDER BY
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 after sorting
operations.
When you have installed MySQL, the `support-files' directory will contain some different `my.cnf' example files, `my-huge.cnf', `my-large.cnf', `my-medium.cnf', and `my-small.cnf', you can use as a base to optimize your system.
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.
Note that if you specicy 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 --help
Make sure that the --help
option is last; otherwise, the effect of any
options listed after it on the command line will not be reflected in the
output.
Most of the following tests are done on Linux with the MySQL benchmarks, but they should give some indication for other operating systems and workloads.
You get the fastest executable when you link with -static
.
On Linux, you will get the fastest code when compiling with pgcc
and -O3
. To compile `sql_yacc.cc' with these options, you
need about 200M memory because gcc/pgcc
needs a lot of memory to
make all functions inline. You should also set CXX=gcc
when
configuring MySQL to avoid inclusion of the libstdc++
library (it is not needed). Note that with some versions of pgcc
,
the resulting code will only run on true Pentium processors, even if you
use the compiler option that you want the resulting code to be working on
all x586 type processors (like AMD).
By just using a better compiler and/or better compiler options you can get a 10-30% speed increase in your application. This is particularly important if you compile the SQL server yourself!
We have tested both the Cygnus CodeFusion and Fujitsu compilers, but when we tested them, neither was sufficiently bug free to allow MySQL to be compiled with optimizations on.
When you compile MySQL you should only include support for the
character sets that you are going to use. (Option --with-charset=xxx
.)
The standard MySQL binary distributions are compiled with support
for all character sets.
Here is a list of some measurements that we have done:
pgcc
and compile everything with -O6
, the
mysqld
server is 1% faster than with gcc
2.95.2.
-static
), the result is 13%
slower on Linux. Note that you still can use a dynamic linked
MySQL library for your client applications. It is the server that is most
critical for performance.
mysqld
binary with strip libexec/mysqld
,
the resulting binary can be up to 4% faster.
localhost
,
MySQL uses a socket file by default.)
--with-debug=full
, most queries will be 20% slower.
Some queries may take substantially longer (for example,
the MySQL benchmarks ran 35% slower). If you use --with-debug
,
the slowdown will be only 15%. For a mysqld
version that has
been compiled with --with-debug=full
, you can disable memory
checking at runtime by starting it with the --skip-safemalloc
option. The end result in this case should be close to when configuring
with --with-debug
.
gcc
3.2.
gcc
2.95.2 for UltraSPARC with the option
-mcpu=v8 -Wa,-xarch=v8plusa
gives 4% more performance.
--log-bin
makes mysqld
1% slower.
gcc
without frame pointers
-fomit-frame-pointer
or -fomit-frame-pointer -ffixed-ebp
makes mysqld
1-4% faster.
The MySQL-Linux distribution provided by MySQL AB used
to be compiled with pgcc
, but we had to go back to regular gcc
because of a bug in pgcc
that would generate the code that does
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 get 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 server variable relevant
to the memory use is given:
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.
thread_stack
), a connection buffer (variable
net_buffer_length
), and a result buffer (variable
net_buffer_length
). The connection buffer and result buffer are
dynamically enlarged up to max_allowed_packet
when needed. When
a query is running, a copy of the current query string is also allocated.
ISAM
and MyISAM
tables are memory mapped. This
is because the 32-bit memory space of 4 GB 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.
read_buffer_size
).
read_rnd_buffer_size
).
HEAP
)
tables. Temporary tables with a large record length (calculated as the
sum of all column lengths) or that contain BLOB
columns are
stored on disk.
One problem in MySQL before Version 3.23.2 is that if an in-memory HEAP
table exceeds the size of tmp_table_size
, you get the error The
table tbl_name is full
. From 3.23.2 on, this is handled
automatically by changing the in-memory HEAP
table to a disk-based
MyISAM
table as necessary. To work around this problem, you can
increase the temporary table size by setting the tmp_table_size
option to mysqld
, or by setting the SQL option
BIG_TABLES
in the client program. See section 7.5.6 SET
Syntax. In MySQL Version 3.20, the maximum size of the
temporary table is record_buffer*16
; if you are using this
version, you have to increase the value of record_buffer
. You can
also start mysqld
with the --big-tables
option to always
store temporary tables on disk. However, this will affect the speed of
many complicated queries.
malloc()
and
free()
.
3 * n
is
allocated (where n
is the maximum row length, not counting BLOB
columns). A BLOB
column uses 5 to 8 bytes plus the length of the
BLOB
data. The ISAM
and MyISAM
storage engines use one
extra row buffer for internal usage.
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.
mysqladmin flush-tables
command (or FLUSH TABLES
statement)
closes all tables that are not in
use and marks all in-use tables to be closed when the currently executing
thread finishes. This will effectively free most in-use memory.
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 have tested
mysqld
with commercial memory-leakage detectors, 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 if the
hostname is in the hostname cache. If not, the thread attempts to resolve the
hostname:
gethostbyaddr_r()
and
gethostbyname_r()
calls, the thread uses them to perform hostname
resolution.
gethostbyaddr()
and
gethostbyname()
instead. Note that 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 only use 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.
If you want to disallow TCP/IP connections entirely, start mysqld
with
the --skip-networking
option.
SET
SyntaxSET [GLOBAL | SESSION] sql_variable=expression, [[GLOBAL | SESSION] sql_variable=expression] ...
SET
sets various options that affect the operation of the
server or your client.
The following examples shows the different syntaxes one can use to set variables:
In old MySQL versions we allowed the use of the SET OPTION
syntax,
but this syntax is now deprecated.
In MySQL 4.0.3 we added the GLOBAL
and SESSION
options
and access to most important startup variables.
LOCAL
can be used as a synonym for SESSION
.
If you set several variables on the same command line, the last used
GLOBAL | SESSION
mode is used.
SET sort_buffer_size=10000; SET @@local.sort_buffer_size=10000; SET GLOBAL sort_buffer_size=1000000, SESSION sort_buffer_size=1000000; SET @@sort_buffer_size=1000000; SET @@global.sort_buffer_size=1000000, @@local.sort_buffer_size=1000000;
The @@variable_name
syntax is supported to make MySQL syntax
compatible with some other databases.
The different system variables you can set are described in the system variable section of this manual. See section 10.4 System Variables.
If you are using SESSION
(the default), the option you set remains
in effect until the current session ends, or until you set the option to
a different value. If you use GLOBAL
, which requires the
SUPER
privilege, the option is remembered and used for new
connections until the server restarts. If you want to make an option
permanent, you should set it in an option file.
See section 4.3.2 Using Option Files.
To avoid incorrect usage, MySQL will produce an error if you use SET
GLOBAL
with a variable that can only be used with SET SESSION
or if
you are not using SET GLOBAL
with a global variable.
If you want to set a SESSION
variable to the GLOBAL
value or a
GLOBAL
value to the MySQL default value, you can set it to
DEFAULT
.
SET max_join_size=DEFAULT;
This is identical to:
SET @@session.max_join_size=@@global.max_join_size;
If you want to restrict the maximum value to which a server variable can be set
with the SET
command, you can specify this maximum by using the
--maximum-variable-name
command line option. See section 5.2.1 mysqld
Command-line Options.
You can get a list of most variables with SHOW VARIABLES
.
See section 13.5.3.4 SHOW VARIABLES
. You can get the value for
a specific value with the @@[global.|local.]variable_name
syntax:
SHOW VARIABLES like "max_join_size"; SHOW GLOBAL VARIABLES like "max_join_size"; SELECT @@max_join_size, @@global.max_join_size;
Here follows a description of the variables that use
a non-standard SET
syntax and some of the other
variables. The other variable definitions can be found in the system
variable section, among the startup options or in the description of
SHOW VARIABLES
.
See section 10.4 System Variables.
See section 5.2.1 mysqld
Command-line Options.
See section 13.5.3.4 SHOW VARIABLES
.
AUTOCOMMIT= 0 | 1
1
, all changes to a table will be done at once. To start
a multi-command transaction, you have to use the BEGIN
statement. See section 13.4.1 START TRANSACTION
, COMMIT
, and ROLLBACK
Syntax. If set to 0
you have to use COMMIT
to accept that transaction or ROLLBACK
to cancel it.
See section 13.4.1 START TRANSACTION
, COMMIT
, and ROLLBACK
Syntax.
Note that when you change AUTOCOMMIT
mode from 0
to 1
,
MySQL performs an automatic COMMIT
of any open transaction.
BIG_TABLES = 0 | 1
1
, all temporary tables are stored on disk rather than in
memory. This will be a little slower, but you will not get the error
The table tbl_name is full
for big SELECT
operations that
require a large temporary table. The default value for a new connection is
0
(that is, use in-memory temporary tables).
This variable previously was named SQL_BIG_TABLES
. In MySQL 4.0, you
should normally never need to set this variable, because MySQL automatically
converts in-memory tables to disk-based tables as necessary.
CHARACTER SET character_set_name | DEFAULT
character_set_name
is
cp1251_koi8
, but you can easily add new mappings by editing the
`sql/convert.cc' file in the MySQL source distribution. The
default mapping can be restored by using a character_set_name
value of
DEFAULT
.
Note that the syntax for setting the CHARACTER SET
option differs
from the syntax for setting the other options.
INSERT_ID = #
INSERT
or ALTER TABLE
command when inserting an AUTO_INCREMENT
value. This is mainly used
with the binary log.
LAST_INSERT_ID = #
LAST_INSERT_ID()
. This is stored in
the binary log when you use LAST_INSERT_ID()
in a command that updates
a table. Setting this variable does not update mysql_insert_id()
.
LOW_PRIORITY_UPDATES = 0 | 1
1
, all INSERT
, UPDATE
, DELETE
, and
LOCK TABLE WRITE
statements wait until there is no pending
SELECT
or LOCK TABLE READ
on the affected table.
This variable previously was named SQL_LOW_PRIORITY_UPDATES
.
MAX_JOIN_SIZE = value | DEFAULT
SELECT
statements that will probably need to examine more
than value
row combinations or is likely to do more than value
disk seeks. By setting this value, you can catch SELECT
statements
where keys are not used properly and that would probably take a long
time. Setting this to a value other than DEFAULT
resets the
SQL_BIG_SELECTS
value to 0
. If you set the
SQL_BIG_SELECTS
value
again, the SQL_MAX_JOIN_SIZE
variable will be ignored. You can
set a default value for this variable by starting mysqld
with the
--max_join_size=value
option. This variable previously was named
SQL_MAX_JOIN_SIZE
.
Note that if a query result already is in the query cache, no result size
check is performed, because the result has already been computed and it will
not burden the server to send it to the client.
PASSWORD = PASSWORD('some password')
PASSWORD FOR user = PASSWORD('some password')
mysql
database can do this. The user should be
given in user@hostname
format, where user
and hostname
are exactly as they are listed in the User
and Host
columns of
the mysql.user
table entry. For example, if you had an entry with
User
and Host
fields of 'bob'
and '%.loc.gov'
,
you would write:
mysql> SET PASSWORD FOR 'bob'@'%.loc.gov' = PASSWORD('newpass');Which is equivalent to:
mysql> UPDATE mysql.user SET Password=PASSWORD('newpass') -> WHERE User='bob' AND Host='%.loc.gov'; mysql> FLUSH PRIVILEGES;
QUERY_CACHE_TYPE = OFF | ON | DEMAND
QUERY_CACHE_TYPE = 0 | 1 | 2
Option | Description |
0 or OFF | Don't cache or retrieve results. |
1 or ON | Cache all results except SELECT SQL_NO_CACHE ... queries.
|
2 or DEMAND | Cache only SELECT SQL_CACHE ... queries.
|
SQL_AUTO_IS_NULL = 0 | 1
1
(default), you can find the last inserted row for a table
that contains an AUTO_INCREMENT
column by using the following construct:
WHERE auto_increment_column IS NULL
. This is used by some
ODBC programs like Access.
SQL_BIG_SELECTS = 0 | 1
0
, MySQL aborts SELECT
statements
that probably will take a very long time (that is, statements for which
the optimizer estimates that the number of of examined rows probably will
exceed the value of MAX_JOIN_SIZE
).
This is useful when an inadvisable WHERE
statement has been
issued. The default value for a new connection is 1
, which allows
all SELECT
statements.
If you set MAX_JOIN_SIZE
to a value other than DEFAULT
,
SQL_BIG_SELECTS
will be set to 0
.
SQL_BUFFER_RESULT = 0 | 1
SQL_BUFFER_RESULT
forces the result from SELECT
statements
to be put into a temporary table. This will help MySQL free the
table locks early and will help in cases where it takes a long time to
send the result set to the client.
SQL_LOG_BIN = 0 | 1
0
, no logging is done to the binary log for the client,
if the client has the SUPER
privilege.
SQL_LOG_OFF = 0 | 1
1
, no logging is done to the standard log for this
client, if the client has the SUPER
privilege.
SQL_LOG_UPDATE = 0 | 1
0
, no logging is done to the update log for the client,
if the client has the SUPER
privilege.
This variable is deprecated starting from version 5.0.0 and mapped to
SQL_LOG_BIN
(see section C.1.2 Changes in release 5.0.0 (22 Dec 2003: Alpha)).
SQL_QUOTE_SHOW_CREATE = 0 | 1
1
, SHOW CREATE TABLE
quotes
table and column names. This is on by default,
so that replication of tables with fancy column names will work.
section 13.5.3.8 SHOW CREATE TABLE
.
SQL_SAFE_UPDATES = 0 | 1
1
, MySQL aborts UPDATE
or
DELETE
statements that do not use a key or LIMIT
in the
WHERE
clause. This makes it possible to catch wrong updates
when creating SQL statements by hand.
SQL_SELECT_LIMIT = value | DEFAULT
SELECT
statements. If
a SELECT
has a LIMIT
clause, the LIMIT
takes precedence
over the value of SQL_SELECT_LIMIT
. The default value for a new
connection is ``unlimited.'' If you have changed the limit, the default value
can be restored by using a SQL_SELECT_LIMIT
value of DEFAULT
.
TIMESTAMP = timestamp_value | DEFAULT
timestamp_value
should be a
Unix epoch timestamp, not a MySQL timestamp.
hdparm
to configure your disk's interface! The
following should be quite good hdparm
options for MySQL (and
probably many other applications):
hdparm -m 16 -d 1Note that performance and reliability when using the above depends on your hardware, so we strongly suggest that you test your system thoroughly after using
hdparm
. Please consult the hdparm
man page for more information. If hdparm
is not used wisely,
filesystem corruption may result, so back up everything before
experimenting!
-o noatime
option. That skips updates
to the last access time in inodes on the filesystem, which avoids
some disk seeks.
-o async
option to set the filesystem to be updated asynchronously. 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 to just symlink databases to a different disk and only symlink tables as a last resort.
On Unix, the way to symlink a database is to first create a directory on some disk where you have free space and then create a symlink to it from the MySQL database directory.
shell> mkdir /dr1/databases/test shell> ln -s /dr1/databases/test mysqld-datadir
MySQL doesn't support that you link one directory to multiple
databases. Replacing a database directory with a symbolic link will
work fine as long as you don't make a symbolic link between databases.
Suppose you have a database db1
under the MySQL data
directory, and then make a symlink db2
that points to db1
:
shell> cd /path/to/datadir shell> ln -s db1 db2
Now, for any table tbl_a
in db1
, there also appears to be
a table tbl_a
in db2
. If one thread updates db1.tbl_a
and another thread updates db2.tbl_a
, there will be problems.
If you really need this, you must change the following code in `mysys/mf_format.c':
if (flag & 32 || (!lstat(to,&stat_buff) && S_ISLNK(stat_buff.st_mode)))
to
if (1)
On Windows you can use internal symbolic links to directories by compiling
MySQL with -DUSE_SYMDIR
. This allows you to put different
databases on different disks. See section 7.6.1.3 Using Symbolic Links for Databases on Windows.
Before MySQL 4.0 you should not symlink tables unless you are
very careful with them. The problem is that if you run ALTER
TABLE
, REPAIR TABLE
, or OPTIMIZE TABLE
on a symlinked
table, the symlinks will be removed and replaced by the original
files. This happens because these statements work by creating a
temporary file in the database directory and replacing the original
file with the temporary file when the statement operation is complete.
You should not symlink tables on systems that don't have a fully
working realpath()
call. (At least Linux and Solaris support
realpath()
). You can check if your system supports symbolic links
by doing SHOW VARIABLES LIKE 'have_symlink'
.
In MySQL 4.0, symlinks are fully supported only for MyISAM
tables. For other table types, you will probably get strange problems
if you try to use symbolic links on files in the operating system with
any of the above commands.
The handling of symbolic links for MyISAM
tables in MySQL 4.0 works
the following way:
mysqld
is
not running) or with SQL by using the DATA DIRECTORY
and INDEX
DIRECTORY
options to CREATE TABLE
.
See section 13.2.5 CREATE TABLE
Syntax.
myisamchk
will not replace a symlink with the datafile or index file.
It works directly on the file a symlink points to. Any temporary files
will be created in the same directory where the datafile or index file is
located.
mysqld
as root
or allow
persons to have write access to the MySQL database directories.
ALTER TABLE RENAME
and you don't move
the table to another database, the symlinks in the database directory
are renamed to the new names and the datafile and index file are
renamed accordingly.
ALTER TABLE RENAME
to move a table to another database,
the table is moved to the other database directory and the old
symlinks and the files to which they pointed are deleted. (In other words,
the new table will not be symlinked.)
--skip-symlink
option to mysqld
to ensure that no one can use mysqld
to drop
or rename a file outside of the data directory.
SHOW CREATE TABLE
doesn't report if the table has symbolic links
prior to MySQL 4.0.15. This is also true for mysqldump
, which uses
SHOW CREATE TABLE
to generate CREATE TABLE
statements.
Things that are not yet supported:
ALTER TABLE
ignores the DATA DIRECTORY
and INDEX
DIRECTORY
table options.
BACKUP TABLE
and RESTORE TABLE
don't respect symbolic
links.
frm
file must never be a symbolic link (as said
previously, only the data and index files can be symbolic links).
Doing this (for example to make synonyms), will produce incorrect
results.
Suppose 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 /path/to/datadir/db1 shell> ln -s tbl1.frm tbl2.frm shell> ln -s tbl1.MYD tbl2.MYD shell> ln -s tbl1.MYI tbl2.MYINow if one thread reads
db1.tbl1
and another thread updates
db1.tbl2
, there will be problems: the query cache will be fooled
(it will believe tbl1
has not been updated so will return
out-of-date results), the ALTER
commands on tbl2
will also
fail.
Beginning with MySQL Version 3.23.16, the mysqld-max
and mysql-max-nt
servers in the MySQL distribution are
compiled with the -DUSE_SYMDIR
option. This allows 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 symbolic links work on Unix, though the
procedure for setting up the link is different.
On Windows, you make a symbolic link to a MySQL database by creating a file
that contains the path to the destination directory. Save the file in
the data directory using the filename `db_name.sym', where
db_name
is the database name.
For example, if the MySQL data directory is `C:\mysql\data'
and you want to have database foo
located at `D:\data\foo',
you should create the file `C:\mysql\data\foo.sym' that contains
the pathname D:\data\foo\
. After that, all tables created in
the database foo
will be created in `D:\data\foo'.
The `D:\data\foo' directory must exist for this to work. Also,
note that the symbolic link will not be used if a directory with
the database name exists in the MySQL data directory. This means
that if you already have a database directory named `foo' in
the data directory, you must move it to `D:\data' before the
symbolic link will be effective. (To avoid problems, the server
should not be running when you move the database directory.)
Note that because of the speed penalty you get when opening every table, we have not enabled this by default even if you have compiled MySQL with support for this. To enable symlinks you should put in your `my.cnf' or `my.ini' file the following entry:
[mysqld] symbolic-links
In MySQL 4.0, symbolic links are enabled by default. If you don't need them,
you can disable them with the skip-symbolic-links
option.
Go to the first, previous, next, last section, table of contents.