Before , the MySQL/MariaDB optimizer relied on storage engines (e.g. InnoDB) to provide statistics for the query optimizer. This approach worked; however it had some deficiencies:
Storage engines provided poor statistics (this was fixed to some degree with the introduction of Persistent Statistics).
The statistics were supplied through the MySQL Storage Engine Interface, which puts a lot of restrictions on what kind of data is supplied (for example, there is no way to get any data about value distribution in a non-indexed column)
There was little control of the statistics. There was no way to "pin" current statistic values, or provide some values on your own, etc.
Engine-independent table statistics lift these limitations.
Statistics are stored in regular tables in the mysql database.
it is possible for a DBA to read and update the values.
More data is collected/used.
are a subset of engine-independent table statistics that can improve the query plan chosen by the optimizer in certain situations.
Statistics are stored in three tables, , and .
Use or update of data from these tables is controlled by variable. Possible values are listed below:
Engine-independent statistics are collected by doing full table and full index scans, and this process can be quite expensive.
The statement can be used to collect table statistics. However, simply running ANALYZE TABLE table_name does not collect engine-independent (or histogram) statistics by default.
When the statement is executed, MariaDB makes a call to the table's storage engine, and the storage engine collects its own statistics for the table. The specific behavior depends on the storage engine. For the default storage engine, see for more information.
may also collect engine-independent statistics for the table. The specific behavior depends on the value of the system variable. Engine-independent statistics will only be collected if one of the following is true:
The system variable is set to complementary or preferably.
The statement includes the PERSISTENT FOR clause.
The system variable is set to preferably_for_queries by default. With this value, engine-independent statistics are used by default if available, but they are not collected by default. If you want to use engine-independent statistics with the default configuration, then you will have to collect them by executing the statement and by specifying the PERSISTENT FOR clause. It is recommended to collect engine-independent statistics on as-needed basis, so typically one will not have engine-independent statistics for all indexes/all columns.
When to collect statistics is very dependent on the dataset. If data changes frequently it may be necessary to collect statistics more frequently, and the benefits may be very noticeable (see ). If the data distribution is relatively static, the costs of collecting may outweigh any benefits.
The syntax for the statement has been extended with the PERSISTENT FOR clause. This clause allows one to collect engine-independent statistics only for particular columns or indexes. This clause also allows one to collect engine-independent statistics, regardless of the value of the system variable. For example:
Statistics for columns using the and data types are not collected. If a column using one of these types is explicitly specified, then a warning is returned.
Statistics are stored in three tables, , and .
It is possible to update statistics tables manually. One should modify the table(s) with regular // statements. Statistics data will be re-read when the tables are re-opened. One way to force all tables to be re-opened is to issue command.
A few scenarios where one might need to update statistics tables manually:
Deleting the statistics. Currently, the command will collect the statistics, but there is no special command to delete statistics.
Running ANALYZE on a different server. To collect engine-independent statistics ANALYZE TABLE does a full table scan, which can put too much load on the server. It is possible to run ANALYZE on the slave, and then take the data from statistics tables on the slave and apply it on the master.
In some cases, knowledge of the database allows one to compute statistics manually in a more efficient way than ANALYZE does. One can compute the statistics manually and put it into the database.
(mariadb.org blog)
This page is licensed: CC BY-SA / Gnu FDL
'never'
The optimizer doesn't use data from statistics tables.
'complementary'
The optimizer uses data from statistics tables if the same kind of data is not provided by the storage engine.
'preferably'
Prefer the data from statistics tables, if it's not available there, use the data from the storage engine.
'complementary_for_queries'
Same as complementary, but for queries only (to avoid needlessly collecting for ANALYZE TABLE).
'preferably_for_queries'
Same as preferably, but for queries only (to avoid needlessly collecting for ANALYZE TABLE). Default.
ANALYZE TABLE table_name PERSISTENT FOR ALL;-- update all engine-independent statistics for all columns and indexes
ANALYZE TABLE tbl PERSISTENT FOR ALL;
-- update specific columns and indexes:
ANALYZE TABLE tbl PERSISTENT FOR COLUMNS (col1,col2,...) INDEXES (idx1,idx2,...);
-- empty lists are allowed:
ANALYZE TABLE tbl PERSISTENT FOR COLUMNS (col1,col2,...) INDEXES ();
ANALYZE TABLE tbl PERSISTENT FOR COLUMNS () INDEXES (idx1,idx2,...);
-- the following will only update mysql.table_stats fields:
ANALYZE TABLE tbl PERSISTENT FOR COLUMNS () INDEXES ();
-- when use_stat_tables is set to 'COMPLEMENTARY' or 'PREFERABLY',
-- a simple ANALYZE TABLE collects engine-independent statistics for all columns and indexes.
SET SESSION use_stat_tables='COMPLEMENTARY';
ANALYZE TABLE tbl;