From e8497370b9557e77c0a791f89712a6ae8505f925 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 4 Jan 2012 17:51:53 -0800 Subject: [PATCH 01/35] The main patch for the MWL#248 back-ported from lp:~igorb-seattle/mysql-server/mysql-azalea-wl4777. --- libmysqld/Makefile.am | 1 + mysql-test/include/system_db_struct.inc | 3 + mysql-test/include/world_schema_utf8.inc | 25 + mysql-test/r/1st.result | 3 + mysql-test/r/connect.result | 9 + mysql-test/r/information_schema.result | 6 + .../r/information_schema_all_engines.result | 2 +- mysql-test/r/log_tables_upgrade.result | 3 + mysql-test/r/mysqlcheck.result | 6 + mysql-test/r/statistics.result | 455 +++++ mysql-test/r/system_mysql_db.result | 34 + mysql-test/suite/pbxt/r/connect.result | 9 + mysql-test/t/statistics.test | 290 +++ mysql-test/t/system_mysql_db_fix30020.test | 3 +- mysql-test/t/system_mysql_db_fix40123.test | 7 +- mysql-test/t/system_mysql_db_fix50030.test | 8 +- mysql-test/t/system_mysql_db_fix50117.test | 8 +- scripts/mysql_system_tables.sql | 5 + sql/CMakeLists.txt | 3 +- sql/Makefile.am | 4 +- sql/field.cc | 20 +- sql/field.h | 131 ++ sql/item_sum.cc | 8 +- sql/mysql_priv.h | 16 + sql/mysqld.cc | 2 + sql/set_var.cc | 6 + sql/sql_base.cc | 73 + sql/sql_class.h | 1 + sql/sql_statistics.cc | 1587 +++++++++++++++++ sql/sql_statistics.h | 63 + sql/sql_table.cc | 21 +- sql/structs.h | 25 + sql/table.cc | 20 +- sql/table.h | 19 + 34 files changed, 2858 insertions(+), 18 deletions(-) create mode 100644 mysql-test/include/world_schema_utf8.inc create mode 100644 mysql-test/r/statistics.result create mode 100644 mysql-test/t/statistics.test create mode 100644 sql/sql_statistics.cc create mode 100644 sql/sql_statistics.h diff --git a/libmysqld/Makefile.am b/libmysqld/Makefile.am index cffde1c7db1..b16da5e55c0 100644 --- a/libmysqld/Makefile.am +++ b/libmysqld/Makefile.am @@ -75,6 +75,7 @@ sqlsources = derror.cc field.cc field_conv.cc strfunc.cc filesort.cc \ sql_update.cc sql_yacc.cc table.cc thr_malloc.cc time.cc \ unireg.cc uniques.cc sql_union.cc hash_filo.cc \ spatial.cc gstream.cc sql_help.cc tztime.cc sql_cursor.cc \ + sql_statistics.cc \ sp_head.cc sp_pcontext.cc sp.cc sp_cache.cc sp_rcontext.cc \ parse_file.cc sql_view.cc sql_trigger.cc my_decimal.cc \ rpl_filter.cc sql_partition.cc sql_builtin.cc sql_plugin.cc \ diff --git a/mysql-test/include/system_db_struct.inc b/mysql-test/include/system_db_struct.inc index 123c82484b9..3d97ff67043 100644 --- a/mysql-test/include/system_db_struct.inc +++ b/mysql-test/include/system_db_struct.inc @@ -16,3 +16,6 @@ show create table proc; show create table event; show create table general_log; show create table slow_log; +show create table table_stat; +show create table column_stat; +show create table index_stat; diff --git a/mysql-test/include/world_schema_utf8.inc b/mysql-test/include/world_schema_utf8.inc new file mode 100644 index 00000000000..2a09c5d32d5 --- /dev/null +++ b/mysql-test/include/world_schema_utf8.inc @@ -0,0 +1,25 @@ +CREATE TABLE Country ( + Code char(3) NOT NULL default '', + Name char(52) NOT NULL default '', + SurfaceArea float(10,2) NOT NULL default '0.00', + Population int(11) NOT NULL default '0', + Capital int(11) default NULL, + PRIMARY KEY (Code), + UNIQUE INDEX (Name) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE City ( + ID int(11) NOT NULL auto_increment, + Name char(35) NOT NULL default '', + Country char(3) NOT NULL default '', + Population int(11) NOT NULL default '0', + PRIMARY KEY (ID), + INDEX (Population), + INDEX (Country) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE CountryLanguage ( + Country char(3) NOT NULL default '', + Language char(30) NOT NULL default '', + Percentage float(3,1) NOT NULL default '0.0', + PRIMARY KEY (Country, Language), + INDEX (Percentage) +) CHARACTER SET utf8 COLLATE utf8_bin; diff --git a/mysql-test/r/1st.result b/mysql-test/r/1st.result index 4a82f8c66e9..7675c9ec35c 100644 --- a/mysql-test/r/1st.result +++ b/mysql-test/r/1st.result @@ -6,6 +6,7 @@ mysql test show tables in mysql; Tables_in_mysql +column_stat columns_priv db event @@ -16,12 +17,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second diff --git a/mysql-test/r/connect.result b/mysql-test/r/connect.result index 7a972f4814a..544e2d29846 100644 --- a/mysql-test/r/connect.result +++ b/mysql-test/r/connect.result @@ -1,6 +1,7 @@ drop table if exists t1,t2; show tables; Tables_in_mysql +column_stat columns_priv db event @@ -11,12 +12,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second @@ -34,6 +37,7 @@ grant ALL on *.* to test@localhost identified by "gambling"; grant ALL on *.* to test@127.0.0.1 identified by "gambling"; show tables; Tables_in_mysql +column_stat columns_priv db event @@ -44,12 +48,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second @@ -75,6 +81,7 @@ ERROR HY000: Password hash should be a 41-digit hexadecimal number set password=old_password('gambling3'); show tables; Tables_in_mysql +column_stat columns_priv db event @@ -85,12 +92,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second diff --git a/mysql-test/r/information_schema.result b/mysql-test/r/information_schema.result index 6694cf48109..1370fb86875 100644 --- a/mysql-test/r/information_schema.result +++ b/mysql-test/r/information_schema.result @@ -95,6 +95,7 @@ USER_STATISTICS VIEWS XTRADB_ADMIN_COMMAND XTRADB_ENHANCEMENTS +column_stat columns_priv db event @@ -105,6 +106,7 @@ help_keyword help_relation help_topic host +index_stat plugin proc procs_priv @@ -115,6 +117,7 @@ t2 t3 t4 t5 +table_stat tables_priv time_zone time_zone_leap_second @@ -132,6 +135,7 @@ TABLE_CONSTRAINTS TABLE_CONSTRAINTS TABLE_PRIVILEGES TABLE_PRIVILEGES TABLE_STATISTICS TABLE_STATISTICS TRIGGERS TRIGGERS +table_stat table_stat tables_priv tables_priv time_zone time_zone time_zone_leap_second time_zone_leap_second @@ -152,6 +156,7 @@ TABLE_CONSTRAINTS TABLE_CONSTRAINTS TABLE_PRIVILEGES TABLE_PRIVILEGES TABLE_STATISTICS TABLE_STATISTICS TRIGGERS TRIGGERS +table_stat table_stat tables_priv tables_priv time_zone time_zone time_zone_leap_second time_zone_leap_second @@ -172,6 +177,7 @@ TABLE_CONSTRAINTS TABLE_CONSTRAINTS TABLE_PRIVILEGES TABLE_PRIVILEGES TABLE_STATISTICS TABLE_STATISTICS TRIGGERS TRIGGERS +table_stat table_stat tables_priv tables_priv time_zone time_zone time_zone_leap_second time_zone_leap_second diff --git a/mysql-test/r/information_schema_all_engines.result b/mysql-test/r/information_schema_all_engines.result index 7a2c548a329..ad172710052 100644 --- a/mysql-test/r/information_schema_all_engines.result +++ b/mysql-test/r/information_schema_all_engines.result @@ -382,4 +382,4 @@ Wildcard: inf_rmation_schema SELECT table_schema, count(*) FROM information_schema.TABLES WHERE table_schema IN ('mysql', 'INFORMATION_SCHEMA', 'test', 'mysqltest') AND table_name<>'ndb_binlog_index' AND table_name<>'ndb_apply_status' GROUP BY TABLE_SCHEMA; table_schema count(*) information_schema 52 -mysql 22 +mysql 25 diff --git a/mysql-test/r/log_tables_upgrade.result b/mysql-test/r/log_tables_upgrade.result index a9d1b41cf2c..53d6b6ce4eb 100644 --- a/mysql-test/r/log_tables_upgrade.result +++ b/mysql-test/r/log_tables_upgrade.result @@ -19,6 +19,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -28,12 +29,14 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.renamed_general_log OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK diff --git a/mysql-test/r/mysqlcheck.result b/mysql-test/r/mysqlcheck.result index 8aa121f9854..45904b0f088 100644 --- a/mysql-test/r/mysqlcheck.result +++ b/mysql-test/r/mysqlcheck.result @@ -3,6 +3,7 @@ drop view if exists v1; drop database if exists client_test_db; mtr.global_suppressions OK mtr.test_suppressions OK +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -12,11 +13,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -24,6 +27,7 @@ mysql.time_zone_name OK mysql.time_zone_transition OK mysql.time_zone_transition_type OK mysql.user OK +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -33,11 +37,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result new file mode 100644 index 00000000000..424dec3bb9d --- /dev/null +++ b/mysql-test/r/statistics.result @@ -0,0 +1,455 @@ +drop table if exists t1,t2; +CREATE VIEW table_stat AS +SELECT * FROM mysql.table_stat; +CREATE VIEW column_stat AS +SELECT db_name, table_name, column_name, +min_value, max_value, +CAST(nulls_ratio AS decimal(12,4)) AS 'nulls_ratio', +CAST(avg_length AS decimal(12,4)) AS 'avg_length', +CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' + FROM mysql.column_stat; +CREATE VIEW index_stat AS +SELECT db_name, table_name, index_name, prefix_arity, +CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' + FROM mysql.index_stat; +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +set optimizer_use_stat_tables='preferably'; +CREATE TABLE t1 ( +a int NOT NULL PRIMARY KEY, +b varchar(32), +c char(16), +d date, +e double, +f bit(3), +INDEX idx1 (b, e), +INDEX idx2(c, d), +INDEX idx3 (d), +INDEX idx4 (e, b, d) +); +INSERT INTO t1 VALUES +(0, NULL, NULL, NULL, NULL, NULL), +(7, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'dddddddd', '1990-05-15', 0.1, b'100'), +(17, 'vvvvvvvvvvvvv', 'aaaa', '1989-03-12', 0.01, b'101'), +(1, 'vvvvvvvvvvvvv', NULL, '1989-03-12', 0.01, b'100'), +(12, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1999-07-23', 0.112, b'001'), +(23, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.1, b'100'), +(8, 'vvvvvvvvvvvvv', 'aaaa', '1999-07-23', 0.1, b'100'), +(22, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'aaaa', '1989-03-12', 0.112, b'001'), +(31, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'aaaa', '1999-07-23', 0.01, b'001'), +(10, NULL, 'aaaa', NULL, 0.01, b'010'), +(5, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1999-07-23', 0.1, b'100'), +(15, 'vvvvvvvvvvvvv', 'ccccccccc', '1990-05-15', 0.1, b'010'), +(30, NULL, 'bbbbbb', NULL, NULL, b'100'), +(38, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', NULL, NULL, NULL), +(18, 'zzzzzzzzzzzzzzzzzz', 'ccccccccc', '1990-05-15', 0.01, b'010'), +(9, 'yyy', 'bbbbbb', '1998-08-28', 0.01, NULL), +(29, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.012, b'010'), +(3, 'yyy', 'dddddddd', '1990-05-15', 0.112, b'010'), +(39, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', NULL, 0.01, b'100'), +(14, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'ccccccccc', '1990-05-15', 0.1, b'100'), +(40, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', '1989-03-12', NULL, NULL), +(44, NULL, 'aaaa', '1989-03-12', NULL, b'010'), +(19, 'vvvvvvvvvvvvv', 'ccccccccc', '1990-05-15', 0.012, b'011'), +(21, 'zzzzzzzzzzzzzzzzzz', 'dddddddd', '1989-03-12', 0.112, b'100'), +(45, NULL, NULL, '1989-03-12', NULL, b'011'), +(2, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'ccccccccc', '1990-05-15', 0.1, b'001'), +(35, 'yyy', 'aaaa', '1990-05-15', 0.05, b'011'), +(4, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.01, b'101'), +(47, NULL, 'aaaa', '1990-05-15', 0.05, b'010'), +(42, NULL, 'ccccccccc', '1989-03-12', 0.01, b'010'), +(32, NULL, 'bbbbbb', '1990-05-15', 0.01, b'011'), +(49, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww' , 'aaaa', '1990-05-15', NULL, NULL), +(43, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww' , 'bbbbbb', '1990-05-15', NULL, b'100'), +(37, 'yyy', NULL, '1989-03-12', 0.05, b'011'), +(41, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'ccccccccc', '1990-05-15', 0.05, NULL), +(34, 'yyy', NULL, NULL, NULL, NULL), +(33, 'zzzzzzzzzzzzzzzzzz', 'dddddddd', '1989-03-12', 0.05, b'011'), +(24, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1990-05-15', 0.01, b'101'), +(11, 'yyy', 'ccccccccc', '1999-07-23', 0.1, NULL), +(25, 'zzzzzzzzzzzzzzzzzz', 'bbb', '1989-03-12', 0.01, b'101'); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +SELECT COUNT(*) FROM t1; +COUNT(*) +40 +SELECT * FROM column_stat +WHERE db_name='test' AND table_name='t1' AND column_name='a'; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +SELECT MIN(t1.a), MAX(t1.a), +(SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / +(SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.a)", +(SELECT COUNT(t1.a) FROM t1) / +(SELECT COUNT(DISTINCT t1.a) FROM t1) AS "AVG_FREQUENCY(t1.a)" +FROM t1; +MIN(t1.a) MAX(t1.a) NULLS_RATIO(t1.a) AVG_FREQUENCY(t1.a) +0 49 0.2000 1.0000 +SELECT * FROM column_stat +WHERE db_name='test' AND table_name='t1' AND column_name='b'; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +SELECT MIN(t1.b), MAX(t1.b), +(SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / +(SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.b)", +(SELECT COUNT(t1.b) FROM t1) / +(SELECT COUNT(DISTINCT t1.b) FROM t1) AS "AVG_FREQUENCY(t1.b)" +FROM t1; +MIN(t1.b) MAX(t1.b) NULLS_RATIO(t1.b) AVG_FREQUENCY(t1.b) +vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 +SELECT * FROM column_stat +WHERE db_name='test' AND table_name='t1' AND column_name='c'; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +SELECT MIN(t1.c), MAX(t1.c), +(SELECT COUNT(*) FROM t1 WHERE t1.c IS NULL) / +(SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.c)", +(SELECT COUNT(t1.c) FROM t1) / +(SELECT COUNT(DISTINCT t1.c) FROM t1) AS "AVG_FREQUENCY(t1.c)" +FROM t1; +MIN(t1.c) MAX(t1.c) NULLS_RATIO(t1.c) AVG_FREQUENCY(t1.c) +aaaa dddddddd 0.1250 7.0000 +SELECT * FROM column_stat +WHERE db_name='test' AND table_name='t1' AND column_name='d'; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +SELECT MIN(t1.d), MAX(t1.d), +(SELECT COUNT(*) FROM t1 WHERE t1.d IS NULL) / +(SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.d)", +(SELECT COUNT(t1.d) FROM t1) / +(SELECT COUNT(DISTINCT t1.d) FROM t1) AS "AVG_FREQUENCY(t1.d)" +FROM t1; +MIN(t1.d) MAX(t1.d) NULLS_RATIO(t1.d) AVG_FREQUENCY(t1.d) +1989-03-12 1999-07-23 0.1500 8.5000 +SELECT * FROM column_stat +WHERE db_name='test' AND table_name='t1' AND column_name='e'; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +SELECT MIN(t1.e), MAX(t1.e), +(SELECT COUNT(*) FROM t1 WHERE t1.e IS NULL) / +(SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.e)", +(SELECT COUNT(t1.e) FROM t1) / +(SELECT COUNT(DISTINCT t1.e) FROM t1) AS "AVG_FREQUENCY(t1.e)" +FROM t1; +MIN(t1.e) MAX(t1.e) NULLS_RATIO(t1.e) AVG_FREQUENCY(t1.e) +0.01 0.112 0.2250 6.2000 +SELECT * FROM index_stat +WHERE db_name='test' AND table_name='t1' AND index_name='idx1'; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +SELECT +(SELECT COUNT(*) FROM t1 WHERE t1.b IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.b) FROM t1 WHERE t1.b IS NOT NULL) +AS 'ARITY 1', +(SELECT COUNT(*) FROM t1 WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.b, t1.e) FROM t1 +WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) +AS 'ARITY 2'; +ARITY 1 ARITY 2 +6.4000 1.6875 +SELECT * FROM index_stat +WHERE db_name='test' AND table_name='t1' AND index_name='idx2'; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +SELECT +(SELECT COUNT(*) FROM t1 WHERE t1.c IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.c) FROM t1 WHERE t1.c IS NOT NULL) +AS 'ARITY 1', +(SELECT COUNT(*) FROM t1 WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.c, t1.d) FROM t1 +WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) +AS 'ARITY 2'; +ARITY 1 ARITY 2 +7.0000 2.3846 +SELECT * FROM index_stat +WHERE db_name='test' AND table_name='t1' AND index_name='idx3'; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx3 1 8.5000 +SELECT +(SELECT COUNT(*) FROM t1 WHERE t1.d IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.d) FROM t1 WHERE t1.d IS NOT NULL) +AS 'ARITY 1'; +ARITY 1 +8.5000 +SELECT * FROM index_stat +WHERE db_name='test' AND table_name='t1' AND index_name='idx4'; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +SELECT +(SELECT COUNT(*) FROM t1 WHERE t1.e IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.e) FROM t1 WHERE t1.e IS NOT NULL) +AS 'ARITY 1', +(SELECT COUNT(*) FROM t1 WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.e, t1.b) FROM t1 +WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL) +AS 'ARITY 2', +(SELECT COUNT(*) FROM t1 +WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) / +(SELECT COUNT(DISTINCT t1.e, t1.b, t1.d) FROM t1 +WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) +AS 'ARITY 3'; +ARITY 1 ARITY 2 ARITY 3 +6.2000 1.6875 1.1304 +CREATE TABLE t2 LIKE t1; +ALTER TABLE t2 ENGINE=InnoDB; +INSERT INTO t2 SELECT * FROM t1; +ANALYZE TABLE t2; +Table Op Msg_type Msg_text +test.t2 analyze status OK +SELECT * FROM table_stat; +db_name table_name cardinality +test t1 40 +test t2 40 +SELECT * FROM column_stat ORDER BY column_name; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t2 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +test t2 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM index_stat ORDER BY index_name, prefix_arity, table_name; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t2 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t2 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t2 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t2 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t2 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t2 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t2 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t2 idx4 2 1.6875 +test t1 idx4 3 1.1304 +test t2 idx4 3 1.1304 +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +ALTER TABLE t1 +DROP INDEX idx1, +DROP INDEX idx4; +ALTER TABLE t1 +MODIFY COLUMN b text, +ADD INDEX idx1 (b(4), e), +ADD INDEX idx4 (e, b(4), d); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b NULL NULL 0.2000 17.1250 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx1 1 NULL +test t1 idx1 2 NULL +test t1 idx4 1 6.2000 +test t1 idx4 2 NULL +test t1 idx4 3 NULL +DROP TABLE t1,t2; +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +set optimizer_use_stat_tables='never'; +set names utf8; +CREATE DATABASE world; +use world; +CREATE TABLE Country ( +Code char(3) NOT NULL default '', +Name char(52) NOT NULL default '', +SurfaceArea float(10,2) NOT NULL default '0.00', +Population int(11) NOT NULL default '0', +Capital int(11) default NULL, +PRIMARY KEY (Code), +UNIQUE INDEX (Name) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE City ( +ID int(11) NOT NULL auto_increment, +Name char(35) NOT NULL default '', +Country char(3) NOT NULL default '', +Population int(11) NOT NULL default '0', +PRIMARY KEY (ID), +INDEX (Population), +INDEX (Country) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE CountryLanguage ( +Country char(3) NOT NULL default '', +Language char(30) NOT NULL default '', +Percentage float(3,1) NOT NULL default '0.0', +PRIMARY KEY (Country, Language), +INDEX (Percentage) +) CHARACTER SET utf8 COLLATE utf8_bin; +set optimizer_use_stat_tables='preferably'; +ANALYZE TABLE Country, City, CountryLanguage; +SELECT * FROM test.table_stat; +db_name table_name cardinality +world Country 239 +world City 4079 +world CountryLanguage 984 +SELECT * FROM test.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +world Country Code ABW ZWE 0.0000 3.0000 1.0000 +world Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +world Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +world Country Population 0 1277558000 0.0000 4.0000 1.0575 +world Country Capital 1 4074 0.0293 4.0000 1.0000 +world City ID 1 4079 0.0000 4.0000 1.0000 +world City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +world City Country ABW ZWE 0.0000 3.0000 17.5819 +world City Population 42 10500000 0.0000 4.0000 1.0467 +world CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 +world CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +world CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT * FROM test.index_stat; +db_name table_name index_name prefix_arity avg_frequency +world Country PRIMARY 1 1.0000 +world Country Name 1 1.0000 +world City PRIMARY 1 1.0000 +world City Population 1 1.0467 +world City Country 1 17.5819 +world CountryLanguage PRIMARY 1 4.2232 +world CountryLanguage PRIMARY 2 1.0000 +world CountryLanguage Percentage 1 2.7640 +use test; +set optimizer_use_stat_tables='never'; +CREATE DATABASE world_innodb; +use world_innodb; +CREATE TABLE Country ( +Code char(3) NOT NULL default '', +Name char(52) NOT NULL default '', +SurfaceArea float(10,2) NOT NULL default '0.00', +Population int(11) NOT NULL default '0', +Capital int(11) default NULL, +PRIMARY KEY (Code), +UNIQUE INDEX (Name) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE City ( +ID int(11) NOT NULL auto_increment, +Name char(35) NOT NULL default '', +Country char(3) NOT NULL default '', +Population int(11) NOT NULL default '0', +PRIMARY KEY (ID), +INDEX (Population), +INDEX (Country) +) CHARACTER SET utf8 COLLATE utf8_bin; +CREATE TABLE CountryLanguage ( +Country char(3) NOT NULL default '', +Language char(30) NOT NULL default '', +Percentage float(3,1) NOT NULL default '0.0', +PRIMARY KEY (Country, Language), +INDEX (Percentage) +) CHARACTER SET utf8 COLLATE utf8_bin; +ALTER TABLE Country ENGINE=InnoDB; +ALTER TABLE City ENGINE=InnoDB; +ALTER TABLE CountryLanguage ENGINE=InnoDB; +set optimizer_use_stat_tables='preferably'; +ANALYZE TABLE Country, City, CountryLanguage; +SELECT * FROM test.table_stat; +db_name table_name cardinality +world Country 239 +world City 4079 +world CountryLanguage 984 +world_innodb Country 239 +world_innodb City 4079 +world_innodb CountryLanguage 984 +SELECT * FROM test.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +world Country Code ABW ZWE 0.0000 3.0000 1.0000 +world Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +world Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +world Country Population 0 1277558000 0.0000 4.0000 1.0575 +world Country Capital 1 4074 0.0293 4.0000 1.0000 +world City ID 1 4079 0.0000 4.0000 1.0000 +world City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +world City Country ABW ZWE 0.0000 3.0000 17.5819 +world City Population 42 10500000 0.0000 4.0000 1.0467 +world CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 +world CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +world CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 +world_innodb Country Code ABW ZWE 0.0000 3.0000 1.0000 +world_innodb Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +world_innodb Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +world_innodb Country Population 0 1277558000 0.0000 4.0000 1.0575 +world_innodb Country Capital 1 4074 0.0293 4.0000 1.0000 +world_innodb City ID 1 4079 0.0000 4.0000 1.0000 +world_innodb City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +world_innodb City Country ABW ZWE 0.0000 3.0000 17.5819 +world_innodb City Population 42 10500000 0.0000 4.0000 1.0467 +world_innodb CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 +world_innodb CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +world_innodb CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT * FROM test.index_stat; +db_name table_name index_name prefix_arity avg_frequency +world Country PRIMARY 1 1.0000 +world Country Name 1 1.0000 +world City PRIMARY 1 1.0000 +world City Population 1 1.0467 +world City Country 1 17.5819 +world CountryLanguage PRIMARY 1 4.2232 +world CountryLanguage PRIMARY 2 1.0000 +world CountryLanguage Percentage 1 2.7640 +world_innodb Country PRIMARY 1 1.0000 +world_innodb Country Name 1 1.0000 +world_innodb City PRIMARY 1 1.0000 +world_innodb City Population 1 1.0467 +world_innodb City Country 1 17.5819 +world_innodb CountryLanguage PRIMARY 1 4.2232 +world_innodb CountryLanguage PRIMARY 2 1.0000 +world_innodb CountryLanguage Percentage 1 2.7640 +use test; +DROP DATABASE world; +DROP DATABASE world_innodb; +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +DROP VIEW test.table_stat; +DROP VIEW test.column_stat; +DROP VIEW test.index_stat; diff --git a/mysql-test/r/system_mysql_db.result b/mysql-test/r/system_mysql_db.result index 5079d72aaea..312383c8ee6 100644 --- a/mysql-test/r/system_mysql_db.result +++ b/mysql-test/r/system_mysql_db.result @@ -1,5 +1,6 @@ show tables; Tables_in_db +column_stat columns_priv db event @@ -10,12 +11,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second @@ -262,5 +265,36 @@ slow_log CREATE TABLE `slow_log` ( `server_id` int(10) unsigned NOT NULL, `sql_text` mediumtext NOT NULL ) ENGINE=CSV DEFAULT CHARSET=utf8 COMMENT='Slow log' +show create table table_stat; +Table Create Table +table_stat CREATE TABLE `table_stat` ( + `db_name` varchar(64) COLLATE utf8_bin NOT NULL, + `table_name` varchar(64) COLLATE utf8_bin NOT NULL, + `cardinality` bigint(21) unsigned DEFAULT NULL, + PRIMARY KEY (`db_name`,`table_name`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Tables' +show create table column_stat; +Table Create Table +column_stat CREATE TABLE `column_stat` ( + `db_name` varchar(64) COLLATE utf8_bin NOT NULL, + `table_name` varchar(64) COLLATE utf8_bin NOT NULL, + `column_name` varchar(64) COLLATE utf8_bin NOT NULL, + `min_value` varchar(255) COLLATE utf8_bin DEFAULT NULL, + `max_value` varchar(255) COLLATE utf8_bin DEFAULT NULL, + `nulls_ratio` double DEFAULT NULL, + `avg_length` double DEFAULT NULL, + `avg_frequency` double DEFAULT NULL, + PRIMARY KEY (`db_name`,`table_name`,`column_name`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Columns' +show create table index_stat; +Table Create Table +index_stat CREATE TABLE `index_stat` ( + `db_name` varchar(64) COLLATE utf8_bin NOT NULL, + `table_name` varchar(64) COLLATE utf8_bin NOT NULL, + `index_name` varchar(64) COLLATE utf8_bin NOT NULL, + `prefix_arity` int(11) unsigned NOT NULL, + `avg_frequency` double DEFAULT NULL, + PRIMARY KEY (`db_name`,`table_name`,`index_name`,`prefix_arity`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Indexes' show tables; Tables_in_test diff --git a/mysql-test/suite/pbxt/r/connect.result b/mysql-test/suite/pbxt/r/connect.result index c8d048f4d38..f4b042a4e84 100644 --- a/mysql-test/suite/pbxt/r/connect.result +++ b/mysql-test/suite/pbxt/r/connect.result @@ -1,6 +1,7 @@ drop table if exists t1,t2; show tables; Tables_in_mysql +column_stat columns_priv db event @@ -11,12 +12,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second @@ -34,6 +37,7 @@ grant ALL on *.* to test@localhost identified by "gambling"; grant ALL on *.* to test@127.0.0.1 identified by "gambling"; show tables; Tables_in_mysql +column_stat columns_priv db event @@ -44,12 +48,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second @@ -75,6 +81,7 @@ ERROR HY000: Password hash should be a 41-digit hexadecimal number set password=old_password('gambling3'); show tables; Tables_in_mysql +column_stat columns_priv db event @@ -85,12 +92,14 @@ help_keyword help_relation help_topic host +index_stat ndb_binlog_index plugin proc procs_priv servers slow_log +table_stat tables_priv time_zone time_zone_leap_second diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test new file mode 100644 index 00000000000..9ea57aca14a --- /dev/null +++ b/mysql-test/t/statistics.test @@ -0,0 +1,290 @@ +--source include/have_innodb.inc +--disable_warnings +drop table if exists t1,t2; +--enable_warnings + +CREATE VIEW table_stat AS +SELECT * FROM mysql.table_stat; + +CREATE VIEW column_stat AS + SELECT db_name, table_name, column_name, + min_value, max_value, + CAST(nulls_ratio AS decimal(12,4)) AS 'nulls_ratio', + CAST(avg_length AS decimal(12,4)) AS 'avg_length', + CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' + FROM mysql.column_stat; + +CREATE VIEW index_stat AS + SELECT db_name, table_name, index_name, prefix_arity, + CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' + FROM mysql.index_stat; + +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +set optimizer_use_stat_tables='preferably'; + +CREATE TABLE t1 ( + a int NOT NULL PRIMARY KEY, + b varchar(32), + c char(16), + d date, + e double, + f bit(3), + INDEX idx1 (b, e), + INDEX idx2(c, d), + INDEX idx3 (d), + INDEX idx4 (e, b, d) +); + +INSERT INTO t1 VALUES + (0, NULL, NULL, NULL, NULL, NULL), + (7, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'dddddddd', '1990-05-15', 0.1, b'100'), + (17, 'vvvvvvvvvvvvv', 'aaaa', '1989-03-12', 0.01, b'101'), + (1, 'vvvvvvvvvvvvv', NULL, '1989-03-12', 0.01, b'100'), + (12, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1999-07-23', 0.112, b'001'), + (23, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.1, b'100'), + (8, 'vvvvvvvvvvvvv', 'aaaa', '1999-07-23', 0.1, b'100'), + (22, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'aaaa', '1989-03-12', 0.112, b'001'), + (31, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'aaaa', '1999-07-23', 0.01, b'001'), + (10, NULL, 'aaaa', NULL, 0.01, b'010'), + (5, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1999-07-23', 0.1, b'100'), + (15, 'vvvvvvvvvvvvv', 'ccccccccc', '1990-05-15', 0.1, b'010'), + (30, NULL, 'bbbbbb', NULL, NULL, b'100'), + (38, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', NULL, NULL, NULL), + (18, 'zzzzzzzzzzzzzzzzzz', 'ccccccccc', '1990-05-15', 0.01, b'010'), + (9, 'yyy', 'bbbbbb', '1998-08-28', 0.01, NULL), + (29, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.012, b'010'), + (3, 'yyy', 'dddddddd', '1990-05-15', 0.112, b'010'), + (39, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', NULL, 0.01, b'100'), + (14, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'ccccccccc', '1990-05-15', 0.1, b'100'), + (40, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb', '1989-03-12', NULL, NULL), + (44, NULL, 'aaaa', '1989-03-12', NULL, b'010'), + (19, 'vvvvvvvvvvvvv', 'ccccccccc', '1990-05-15', 0.012, b'011'), + (21, 'zzzzzzzzzzzzzzzzzz', 'dddddddd', '1989-03-12', 0.112, b'100'), + (45, NULL, NULL, '1989-03-12', NULL, b'011'), + (2, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'ccccccccc', '1990-05-15', 0.1, b'001'), + (35, 'yyy', 'aaaa', '1990-05-15', 0.05, b'011'), + (4, 'vvvvvvvvvvvvv', 'dddddddd', '1999-07-23', 0.01, b'101'), + (47, NULL, 'aaaa', '1990-05-15', 0.05, b'010'), + (42, NULL, 'ccccccccc', '1989-03-12', 0.01, b'010'), + (32, NULL, 'bbbbbb', '1990-05-15', 0.01, b'011'), + (49, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww' , 'aaaa', '1990-05-15', NULL, NULL), + (43, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww' , 'bbbbbb', '1990-05-15', NULL, b'100'), + (37, 'yyy', NULL, '1989-03-12', 0.05, b'011'), + (41, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'ccccccccc', '1990-05-15', 0.05, NULL), + (34, 'yyy', NULL, NULL, NULL, NULL), + (33, 'zzzzzzzzzzzzzzzzzz', 'dddddddd', '1989-03-12', 0.05, b'011'), + (24, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd', '1990-05-15', 0.01, b'101'), + (11, 'yyy', 'ccccccccc', '1999-07-23', 0.1, NULL), + (25, 'zzzzzzzzzzzzzzzzzz', 'bbb', '1989-03-12', 0.01, b'101'); + +ANALYZE TABLE t1; + +SELECT * FROM table_stat; +SELECT * FROM column_stat; +SELECT * FROM index_stat; + +SELECT COUNT(*) FROM t1; + +SELECT * FROM column_stat + WHERE db_name='test' AND table_name='t1' AND column_name='a'; +SELECT MIN(t1.a), MAX(t1.a), + (SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / + (SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.a)", + (SELECT COUNT(t1.a) FROM t1) / + (SELECT COUNT(DISTINCT t1.a) FROM t1) AS "AVG_FREQUENCY(t1.a)" +FROM t1; + +SELECT * FROM column_stat + WHERE db_name='test' AND table_name='t1' AND column_name='b'; +SELECT MIN(t1.b), MAX(t1.b), + (SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / + (SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.b)", + (SELECT COUNT(t1.b) FROM t1) / + (SELECT COUNT(DISTINCT t1.b) FROM t1) AS "AVG_FREQUENCY(t1.b)" +FROM t1; + +SELECT * FROM column_stat + WHERE db_name='test' AND table_name='t1' AND column_name='c'; +SELECT MIN(t1.c), MAX(t1.c), + (SELECT COUNT(*) FROM t1 WHERE t1.c IS NULL) / + (SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.c)", + (SELECT COUNT(t1.c) FROM t1) / + (SELECT COUNT(DISTINCT t1.c) FROM t1) AS "AVG_FREQUENCY(t1.c)" +FROM t1; + +SELECT * FROM column_stat + WHERE db_name='test' AND table_name='t1' AND column_name='d'; +SELECT MIN(t1.d), MAX(t1.d), + (SELECT COUNT(*) FROM t1 WHERE t1.d IS NULL) / + (SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.d)", + (SELECT COUNT(t1.d) FROM t1) / + (SELECT COUNT(DISTINCT t1.d) FROM t1) AS "AVG_FREQUENCY(t1.d)" +FROM t1; + +SELECT * FROM column_stat + WHERE db_name='test' AND table_name='t1' AND column_name='e'; +SELECT MIN(t1.e), MAX(t1.e), + (SELECT COUNT(*) FROM t1 WHERE t1.e IS NULL) / + (SELECT COUNT(*) FROM t1) AS "NULLS_RATIO(t1.e)", + (SELECT COUNT(t1.e) FROM t1) / + (SELECT COUNT(DISTINCT t1.e) FROM t1) AS "AVG_FREQUENCY(t1.e)" +FROM t1; + +SELECT * FROM index_stat + WHERE db_name='test' AND table_name='t1' AND index_name='idx1'; +SELECT + (SELECT COUNT(*) FROM t1 WHERE t1.b IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.b) FROM t1 WHERE t1.b IS NOT NULL) + AS 'ARITY 1', + (SELECT COUNT(*) FROM t1 WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.b, t1.e) FROM t1 + WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) + AS 'ARITY 2'; + +SELECT * FROM index_stat + WHERE db_name='test' AND table_name='t1' AND index_name='idx2'; +SELECT + (SELECT COUNT(*) FROM t1 WHERE t1.c IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.c) FROM t1 WHERE t1.c IS NOT NULL) + AS 'ARITY 1', + (SELECT COUNT(*) FROM t1 WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.c, t1.d) FROM t1 + WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) + AS 'ARITY 2'; + +SELECT * FROM index_stat + WHERE db_name='test' AND table_name='t1' AND index_name='idx3'; +SELECT + (SELECT COUNT(*) FROM t1 WHERE t1.d IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.d) FROM t1 WHERE t1.d IS NOT NULL) + AS 'ARITY 1'; + +SELECT * FROM index_stat + WHERE db_name='test' AND table_name='t1' AND index_name='idx4'; +SELECT + (SELECT COUNT(*) FROM t1 WHERE t1.e IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.e) FROM t1 WHERE t1.e IS NOT NULL) + AS 'ARITY 1', + (SELECT COUNT(*) FROM t1 WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.e, t1.b) FROM t1 + WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL) + AS 'ARITY 2', + (SELECT COUNT(*) FROM t1 + WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) / + (SELECT COUNT(DISTINCT t1.e, t1.b, t1.d) FROM t1 + WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) + AS 'ARITY 3'; + + +CREATE TABLE t2 LIKE t1; +ALTER TABLE t2 ENGINE=InnoDB; +INSERT INTO t2 SELECT * FROM t1; + +ANALYZE TABLE t2; + +SELECT * FROM table_stat; +SELECT * FROM column_stat ORDER BY column_name; +SELECT * FROM index_stat ORDER BY index_name, prefix_arity, table_name; + + +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +ALTER TABLE t1 + DROP INDEX idx1, + DROP INDEX idx4; +ALTER TABLE t1 + MODIFY COLUMN b text, + ADD INDEX idx1 (b(4), e), + ADD INDEX idx4 (e, b(4), d); + +ANALYZE TABLE t1; + +SELECT * FROM column_stat; +SELECT * FROM index_stat; + +DROP TABLE t1,t2; + +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +set optimizer_use_stat_tables='never'; + +set names utf8; + +CREATE DATABASE world; + +use world; + +--source include/world_schema_utf8.inc + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/world.inc +--enable_warnings +--enable_result_log +--enable_query_log + +set optimizer_use_stat_tables='preferably'; + +--disable_result_log +ANALYZE TABLE Country, City, CountryLanguage; +--enable_result_log + +SELECT * FROM test.table_stat; +SELECT * FROM test.column_stat; +SELECT * FROM test.index_stat; + +use test; + +set optimizer_use_stat_tables='never'; + +CREATE DATABASE world_innodb; + +use world_innodb; + +--source include/world_schema_utf8.inc + +ALTER TABLE Country ENGINE=InnoDB; +ALTER TABLE City ENGINE=InnoDB; +ALTER TABLE CountryLanguage ENGINE=InnoDB; + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/world.inc +--enable_warnings +--enable_result_log +--enable_query_log + +set optimizer_use_stat_tables='preferably'; + +--disable_result_log +ANALYZE TABLE Country, City, CountryLanguage; +--enable_result_log + +SELECT * FROM test.table_stat; +SELECT * FROM test.column_stat; +SELECT * FROM test.index_stat; + +use test; + +DROP DATABASE world; +DROP DATABASE world_innodb; + +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +DROP VIEW test.table_stat; +DROP VIEW test.column_stat; +DROP VIEW test.index_stat; + + + \ No newline at end of file diff --git a/mysql-test/t/system_mysql_db_fix30020.test b/mysql-test/t/system_mysql_db_fix30020.test index 0a7d9dad7c9..e5f743f25fe 100644 --- a/mysql-test/t/system_mysql_db_fix30020.test +++ b/mysql-test/t/system_mysql_db_fix30020.test @@ -97,7 +97,8 @@ INSERT INTO user VALUES ('localhost','', '','N','N','N','N','N','N','N','N',' DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, -time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index; +time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index, +table_stat, column_stat, index_stat; -- enable_query_log diff --git a/mysql-test/t/system_mysql_db_fix40123.test b/mysql-test/t/system_mysql_db_fix40123.test index 08d40bdae0f..4a91872a27a 100644 --- a/mysql-test/t/system_mysql_db_fix40123.test +++ b/mysql-test/t/system_mysql_db_fix40123.test @@ -59,6 +59,11 @@ CREATE TABLE time_zone_transition_type ( Time_zone_id int unsigned NOT NULL, CREATE TABLE time_zone_leap_second ( Transition_time bigint signed NOT NULL, Correction int signed NOT NULL, PRIMARY KEY TranTime (Transition_time) ) engine=MyISAM CHARACTER SET utf8 comment='Leap seconds information for time zones'; +CREATE TABLE table_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, cardinality bigint(21) unsigned DEFAULT NULL, PRIMARY KEY (db_name,table_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Tables'; + +CREATE TABLE column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio double DEFAULT NULL, avg_length double DEFAULT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; + +CREATE TABLE index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; # Run the mysql_fix_privilege_tables.sql using "mysql --force" --exec $MYSQL --force test < $MYSQL_FIX_PRIVILEGE_TABLES > $MYSQLTEST_VARDIR/log/system_mysql_db_fix40123.log 2>&1 @@ -72,7 +77,7 @@ CREATE TABLE time_zone_leap_second ( Transition_time bigint signed NOT NULL, -- disable_query_log # Drop all tables created by this test -DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index; +DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index, table_stat, column_stat, index_stat; -- enable_query_log diff --git a/mysql-test/t/system_mysql_db_fix50030.test b/mysql-test/t/system_mysql_db_fix50030.test index 41e85661fe8..cabef0f6b8a 100644 --- a/mysql-test/t/system_mysql_db_fix50030.test +++ b/mysql-test/t/system_mysql_db_fix50030.test @@ -66,6 +66,12 @@ CREATE TABLE servers ( Server_name char(64) NOT NULL DEFAULT '', Host char(64) N INSERT INTO servers VALUES ('test','localhost','test','root','', 0,'','mysql','root'); +CREATE TABLE table_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, cardinality bigint(21) unsigned DEFAULT NULL, PRIMARY KEY (db_name,table_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Tables'; + +CREATE TABLE column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio double DEFAULT NULL, avg_length double DEFAULT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; + +CREATE TABLE index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; + # Run the mysql_fix_privilege_tables.sql using "mysql --force" --exec $MYSQL --force test < $MYSQL_FIX_PRIVILEGE_TABLES > $MYSQLTEST_VARDIR/log/system_mysql_db_fix50030.log 2>&1 @@ -78,7 +84,7 @@ INSERT INTO servers VALUES ('test','localhost','test','root','', 0,'','mysql','r -- disable_query_log # Drop all tables created by this test -DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index; +DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index, table_stat, column_stat, index_stat; -- enable_query_log diff --git a/mysql-test/t/system_mysql_db_fix50117.test b/mysql-test/t/system_mysql_db_fix50117.test index bed00239081..c2db3f191b0 100644 --- a/mysql-test/t/system_mysql_db_fix50117.test +++ b/mysql-test/t/system_mysql_db_fix50117.test @@ -85,6 +85,12 @@ CREATE TABLE IF NOT EXISTS event ( db char(64) CHARACTER SET utf8 COLLATE utf8_b CREATE TABLE IF NOT EXISTS ndb_binlog_index (Position BIGINT UNSIGNED NOT NULL, File VARCHAR(255) NOT NULL, epoch BIGINT UNSIGNED NOT NULL, inserts BIGINT UNSIGNED NOT NULL, updates BIGINT UNSIGNED NOT NULL, deletes BIGINT UNSIGNED NOT NULL, schemaops BIGINT UNSIGNED NOT NULL, PRIMARY KEY(epoch)) ENGINE=MYISAM; +CREATE TABLE table_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, cardinality bigint(21) unsigned DEFAULT NULL, PRIMARY KEY (db_name,table_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Tables'; + +CREATE TABLE column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio double DEFAULT NULL, avg_length double DEFAULT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; + +CREATE TABLE index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; + # Run the mysql_fix_privilege_tables.sql using "mysql --force" --exec $MYSQL --force test < $MYSQL_FIX_PRIVILEGE_TABLES > $MYSQLTEST_VARDIR/log/system_mysql_db_fix50117.log 2>&1 @@ -97,7 +103,7 @@ CREATE TABLE IF NOT EXISTS ndb_binlog_index (Position BIGINT UNSIGNED NOT NULL, -- disable_query_log # Drop all tables created by this test -DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index; +DROP TABLE db, host, user, func, plugin, tables_priv, columns_priv, procs_priv, servers, help_category, help_keyword, help_relation, help_topic, proc, time_zone, time_zone_leap_second, time_zone_name, time_zone_transition, time_zone_transition_type, general_log, slow_log, event, ndb_binlog_index, table_stat, column_stat, index_stat; -- enable_query_log diff --git a/scripts/mysql_system_tables.sql b/scripts/mysql_system_tables.sql index 6676b73e0f7..05cbc401612 100644 --- a/scripts/mysql_system_tables.sql +++ b/scripts/mysql_system_tables.sql @@ -102,3 +102,8 @@ CREATE TABLE IF NOT EXISTS event ( db char(64) CHARACTER SET utf8 COLLATE utf8_b CREATE TABLE IF NOT EXISTS ndb_binlog_index (Position BIGINT UNSIGNED NOT NULL, File VARCHAR(255) NOT NULL, epoch BIGINT UNSIGNED NOT NULL, inserts BIGINT UNSIGNED NOT NULL, updates BIGINT UNSIGNED NOT NULL, deletes BIGINT UNSIGNED NOT NULL, schemaops BIGINT UNSIGNED NOT NULL, PRIMARY KEY(epoch)) ENGINE=MYISAM; +CREATE TABLE IF NOT EXISTS table_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, cardinality bigint(21) unsigned DEFAULT NULL, PRIMARY KEY (db_name,table_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Tables'; + +CREATE TABLE IF NOT EXISTS column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio double DEFAULT NULL, avg_length double DEFAULT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; + +CREATE TABLE IF NOT EXISTS index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; diff --git a/sql/CMakeLists.txt b/sql/CMakeLists.txt index 4354bfc60fb..617de134bd2 100644 --- a/sql/CMakeLists.txt +++ b/sql/CMakeLists.txt @@ -69,7 +69,8 @@ SET (SQL_SOURCE sql_map.cc sql_parse.cc sql_partition.cc sql_plugin.cc sql_prepare.cc sql_rename.cc debug_sync.cc debug_sync.h - sql_repl.cc sql_select.cc sql_show.cc sql_state.c sql_string.cc + sql_repl.cc sql_select.cc sql_show.cc sql_state.c + sql_statistics.cc sql_string.cc sql_table.cc sql_test.cc sql_trigger.cc sql_udf.cc sql_union.cc sql_update.cc sql_view.cc strfunc.cc table.cc thr_malloc.cc time.cc tztime.cc uniques.cc unireg.cc item_xmlfunc.cc diff --git a/sql/Makefile.am b/sql/Makefile.am index 291f662328b..ed58c43859b 100644 --- a/sql/Makefile.am +++ b/sql/Makefile.am @@ -73,7 +73,7 @@ noinst_HEADERS = item.h item_func.h item_sum.h item_cmpfunc.h \ log_event_old.h rpl_record_old.h \ sql_sort.h sql_cache.h set_var.h \ spatial.h gstream.h client_settings.h tzfile.h \ - tztime.h my_decimal.h\ + tztime.h my_decimal.h sql_statistics.h \ sp_head.h sp_pcontext.h sp_rcontext.h sp.h sp_cache.h \ parse_file.h sql_view.h sql_trigger.h \ sql_array.h sql_cursor.h events.h scheduler.h \ @@ -127,7 +127,7 @@ mysqld_SOURCES = sql_lex.cc sql_handler.cc sql_partition.cc \ repl_failsafe.h repl_failsafe.cc \ sql_olap.cc sql_view.cc \ gstream.cc spatial.cc sql_help.cc sql_cursor.cc \ - tztime.cc my_decimal.cc\ + tztime.cc my_decimal.cc sql_statistics.cc \ sp_head.cc sp_pcontext.cc sp_rcontext.cc sp.cc \ sp_cache.cc parse_file.cc sql_trigger.cc \ event_scheduler.cc event_data_objects.cc \ diff --git a/sql/field.cc b/sql/field.cc index 934816ba381..cb0b467f7ca 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -70,7 +70,7 @@ const char field_separator=','; ((ulong) ((LL(1) << min(arg, 4) * 8) - LL(1))) #define ASSERT_COLUMN_MARKED_FOR_READ DBUG_ASSERT(!table || (!table->read_set || bitmap_is_set(table->read_set, field_index))) -#define ASSERT_COLUMN_MARKED_FOR_WRITE_OR_COMPUTED DBUG_ASSERT(!table || (!table->write_set || bitmap_is_set(table->write_set, field_index) || bitmap_is_set(table->vcol_set, field_index))) +#define ASSERT_COLUMN_MARKED_FOR_WRITE_OR_COMPUTED DBUG_ASSERT(is_stat_field || !table || (!table->write_set || bitmap_is_set(table->write_set, field_index) || bitmap_is_set(table->vcol_set, field_index))) /* Rules for merging different types of fields in UNION @@ -1330,7 +1330,8 @@ Field::Field(uchar *ptr_arg,uint32 length_arg,uchar *null_ptr_arg, flags=null_ptr ? 0: NOT_NULL_FLAG; comment.str= (char*) ""; comment.length=0; - field_index= 0; + field_index= 0; + is_stat_field= FALSE; } @@ -1817,6 +1818,21 @@ Field *Field::clone(MEM_ROOT *root, struct st_table *new_table) } + +Field *Field::clone(MEM_ROOT *root, TABLE *new_table, my_ptrdiff_t diff, + bool stat_flag) +{ + Field *tmp; + if ((tmp= (Field*) memdup_root(root,(char*) this,size_of()))) + { + tmp->init(new_table); + tmp->move_field_offset(diff); + } + tmp->is_stat_field= stat_flag; + return tmp; +} + + /**************************************************************************** Field_null, a field that always return NULL ****************************************************************************/ diff --git a/sql/field.h b/sql/field.h index 933bbe2c018..04b7baac89a 100644 --- a/sql/field.h +++ b/sql/field.h @@ -33,6 +33,7 @@ class Send_field; class Protocol; class Create_field; class Relay_log_info; +class Count_distinct_field; struct ha_field_option_struct; struct st_cache_field; @@ -183,6 +184,57 @@ public: */ bool is_created_from_null_item; + bool is_stat_field; /* TRUE in Field objects created for column min/max values */ + + /* Statistical data on a column */ + class Column_statistics + { + public: + /* + Bitmap indicating what statistical characteristics + are available for the column + */ + uint32 column_stat_nulls; + + /* Minimum value for the column */ + Field *min_value; + /* Maximum value for the column */ + Field *max_value; + /* + The ratio Z/N, where N is the total number of rows, + Z is the number of nulls in the column + */ + double nulls_ratio; + /* + Average number of bytes occupied by the representation of a + value of the column in memory buffers such as join buffer. + CHAR values are stripped of trailing spaces. + Flexible values are stripped of their length prefixes. + */ + double avg_length; + /* + The ratio N/D, where N is the number of rows with null value + in the column, D the number of distinct values among them + */ + double avg_frequency; + }; + + /* + This structure is used for statistical data on the column + that has been read from the statistical table column_stat + */ + Column_statistics read_stat; + /* + This structure is used for statistical data on the column that + is collected by the function collect_statistics_for_table + */ + Column_statistics write_stat; + + /* These members are used only when collecting statistics on the column */ + ha_rows nulls; + ulonglong column_total_length; + Count_distinct_field *count_distinct; + /* This is additional data provided for any computed(virtual) field. In particular it includes a pointer to the item by which this field @@ -284,6 +336,26 @@ public: virtual uint32 data_length() { return pack_length(); } virtual uint32 sort_length() const { return pack_length(); } + /* + Get the number bytes occupied by the value in the field. + CHAR values are stripped of trailing spaces. + Flexible values are stripped of their length. + */ + virtual uint32 value_length() + { + uint len; + if (!zero_pack() && + (type() == MYSQL_TYPE_STRING && + (len= pack_length()) >= 4 && len < 256)) + { + uchar *str, *end; + for (str= ptr, end= str+len; end > str && end[-1] == ' '; end--); + len=(uint) (end-str); + return len; + } + return data_length(); + } + /** Get the maximum size of the data in packed format. @@ -325,6 +397,36 @@ public: { return cmp(a, b); } virtual int key_cmp(const uchar *str, uint length) { return cmp(ptr,str); } + /* + Update the value m of the 'min_val' field with the current value v + of this field if force_update is set to TRUE or if v < m. + Return TRUE if the value has been updated. + */ + virtual bool update_min(Field *min_val, bool force_update) + { + bool update_fl= force_update || cmp(ptr, min_val->ptr) < 0; + if (update_fl) + { + min_val->set_notnull(); + memcpy(min_val->ptr, ptr, pack_length()); + } + return update_fl; + } + /* + Update the value m of the 'max_val' field with the current value v + of this field if force_update is set to TRUE or if v > m. + Return TRUE if the value has been updated. + */ + virtual bool update_max(Field *max_val, bool force_update) + { + bool update_fl= force_update || cmp(ptr, max_val->ptr) > 0; + if (update_fl) + { + max_val->set_notnull(); + memcpy(max_val->ptr, ptr, pack_length()); + } + return update_fl; + } virtual uint decimals() const { return 0; } /* Caller beware: sql_type can change str.Ptr, so check @@ -396,6 +498,8 @@ public: uchar *new_ptr, uchar *new_null_ptr, uint new_null_bit); Field *clone(MEM_ROOT *mem_root, struct st_table *new_table); + Field *clone(MEM_ROOT *mem_root, TABLE *new_table, my_ptrdiff_t diff, + bool stat_flag= FALSE); inline void move_field(uchar *ptr_arg,uchar *null_ptr_arg,uchar null_bit_arg) { ptr=ptr_arg; null_ptr=null_ptr_arg; null_bit=null_bit_arg; @@ -1785,6 +1889,10 @@ public: int cmp_binary(const uchar *a,const uchar *b, uint32 max_length=~0L); int key_cmp(const uchar *,const uchar*); int key_cmp(const uchar *str, uint length); + /* Never update the value of min_val for a blob field */ + bool update_min(Field *min_val, bool force_update) { return FALSE; } + /* Never update the value of max_val for a blob field */ + bool update_max(Field *max_val, bool force_update) { return FALSE; } uint32 key_length() const { return 0; } void sort_string(uchar *buff,uint length); uint32 pack_length() const @@ -1802,6 +1910,7 @@ public: { return (uint32) (packlength); } uint row_pack_length() { return pack_length_no_ptr(); } uint32 sort_length() const; + uint32 value_length() { return get_length(); } virtual uint32 max_data_length() const { return (uint32) (((ulonglong) 1 << (packlength*8)) -1); @@ -2059,6 +2168,28 @@ public: { return cmp_binary((uchar *) a, (uchar *) b); } int key_cmp(const uchar *str, uint length); int cmp_offset(uint row_offset); + bool update_min(Field *min_val, bool force_update) + { + longlong val= val_int(); + bool update_fl= force_update || val < min_val->val_int(); + if (update_fl) + { + min_val->set_notnull(); + min_val->store(val, FALSE); + } + return update_fl; + } + bool update_max(Field *max_val, bool force_update) + { + longlong val= val_int(); + bool update_fl= force_update || val > max_val->val_int(); + if (update_fl) + { + max_val->set_notnull(); + max_val->store(val, FALSE); + } + return update_fl; + } void get_image(uchar *buff, uint length, CHARSET_INFO *cs) { get_key_image(buff, length, itRAW); } void set_image(const uchar *buff,uint length, CHARSET_INFO *cs) diff --git a/sql/item_sum.cc b/sql/item_sum.cc index 183f8ccff10..67837bdfde8 100644 --- a/sql/item_sum.cc +++ b/sql/item_sum.cc @@ -887,14 +887,14 @@ C_MODE_START /* Declarations for auxilary C-callbacks */ -static int simple_raw_key_cmp(void* arg, const void* key1, const void* key2) +int simple_raw_key_cmp(void* arg, const void* key1, const void* key2) { return memcmp(key1, key2, *(uint *) arg); } -static int item_sum_distinct_walk(void *element, element_count num_of_dups, - void *item) +int item_sum_distinct_walk(void *element, element_count num_of_dups, + void *item) { return ((Item_sum_distinct*) (item))->unique_walk_function(element); } @@ -2362,7 +2362,7 @@ int composite_key_cmp(void* arg, uchar* key1, uchar* key2) C_MODE_START -static int count_distinct_walk(void *elem, element_count count, void *arg) +int count_distinct_walk(void *elem, element_count count, void *arg) { (*((ulonglong*)arg))++; return 0; diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index fbd0d8549f7..d9d61a84684 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -1519,6 +1519,12 @@ find_field_in_table_sef(TABLE *table, const char *name); int update_virtual_fields(THD *thd, TABLE *table, bool ignore_stored= FALSE); int dynamic_column_error_message(enum_dyncol_func_result rc); +int read_statistics_for_table(THD *thd, TABLE *table); +int collect_statistics_for_table(THD *thd, TABLE *table); +int update_statistics_for_table(THD *thd, TABLE *table); + +extern TYPELIB optimizer_use_stat_tables_typelib; + #endif /* MYSQL_SERVER */ #ifdef HAVE_OPENSSL @@ -1935,6 +1941,9 @@ void mysql_wait_completed_table(ALTER_PARTITION_PARAM_TYPE *lpt, TABLE *my_table /* Functions to work with system tables. */ bool open_system_tables_for_read(THD *thd, TABLE_LIST *table_list, Open_tables_state *backup); +bool unlock_tables_n_open_system_tables_for_write(THD *thd, + TABLE_LIST *table_list, + Open_tables_state *backup); void close_system_tables(THD *thd, Open_tables_state *backup); TABLE *open_system_table_for_update(THD *thd, TABLE_LIST *one_table); @@ -2589,6 +2598,13 @@ Item *get_system_var(THD *thd, enum_var_type var_type, LEX_STRING name, LEX_STRING component); int get_var_with_binlog(THD *thd, enum_sql_command sql_command, LEX_STRING &name, user_var_entry **out_entry); + +/* item_sum.cc */ +extern "C" int simple_raw_key_cmp(void* arg, const void* key1, + const void* key2); +extern "C" int count_distinct_walk(void *elem, element_count count, void *arg); +int simple_str_key_cmp(void* arg, uchar* key1, uchar* key2); + /* log.cc */ bool flush_error_log(void); diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 1a60d996fed..4868ded7d00 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -3759,6 +3759,8 @@ static int init_common_variables(const char *conf_file_name, int argc, global_system_variables.character_set_results= default_charset_info; global_system_variables.character_set_client= default_charset_info; + global_system_variables.optimizer_use_stat_tables= 0; + if (!(character_set_filesystem= get_charset_by_csname(character_set_filesystem_name, MY_CS_PRIMARY, MYF(MY_WME)))) diff --git a/sql/set_var.cc b/sql/set_var.cc index e6c1bf94135..3c9ba3e783c 100644 --- a/sql/set_var.cc +++ b/sql/set_var.cc @@ -537,6 +537,12 @@ static sys_var_thd_ulong sys_progress_report_time(&vars, "progress_report_time", &SV::progress_report_time); +static sys_var_thd_enum sys_optimizer_use_stat_tables(&vars, + "optimizer_use_stat_tables", + &SV::optimizer_use_stat_tables, + &optimizer_use_stat_tables_typelib, + NULL); + static sys_var_const sys_pid_file(&vars, "pid_file", OPT_GLOBAL, SHOW_CHAR, (uchar*) pidfile_name); diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 558e7b0aa9e..5a4e2f53fe9 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4855,6 +4855,13 @@ int open_tables(THD *thd, TABLE_LIST **start, uint *counter, uint flags) parent_l->next_global= *parent_l->table->child_last_l; } + if (thd->variables.optimizer_use_stat_tables > 0) + { + if (tables->table && tables->table->s && + tables->table->s->table_category != TABLE_CATEGORY_SYSTEM) + (void) read_statistics_for_table(thd, tables->table); + } + if (refresh) // Refresh in progress { /* @@ -9495,6 +9502,72 @@ error: } +/* + Unlock opened tables and open and lock system tables for write. + + SYNOPSIS + open_system_tables_for_read() + thd Thread context. + table_list List of tables to open. + backup Pointer to Open_tables_state instance where + information about currently open tables will be + saved, and from which will be restored when we will + end work with system tables. + + DESCRIPTION + The function first unlocks the opened tables, but do not close them. + Then it opens and locks for write the specified system tables. + + NOTE + The system tables cannot be locked for write without unlocking + the current opened tables. Yet in some cases we still need valid TABLE + structures for these tables to be able to extract data that is to be + written into the system tables. + This function is used when updating the statistical tables. + + RETURN + FALSE Success + TRUE Error +*/ + +bool +unlock_tables_n_open_system_tables_for_write(THD *thd, + TABLE_LIST *table_list, + Open_tables_state *backup) +{ + Query_tables_list query_tables_list_backup; + LEX *lex= thd->lex; + + DBUG_ENTER("unlock_tables_n_open_system_tables_for_write"); + + mysql_unlock_tables(thd, thd->lock); + thd->lock= 0; + + lex->reset_n_backup_query_tables_list(&query_tables_list_backup); + thd->reset_n_backup_open_tables_state(backup); + + if (open_and_lock_tables_derived(thd, table_list, FALSE)) + { + lex->restore_backup_query_tables_list(&query_tables_list_backup); + goto error; + } + + for (TABLE_LIST *tables= table_list; tables; tables= tables->next_global) + { + DBUG_ASSERT(tables->table->s->table_category == TABLE_CATEGORY_SYSTEM); + tables->table->use_all_columns(); + } + lex->restore_backup_query_tables_list(&query_tables_list_backup); + + DBUG_RETURN(FALSE); + +error: + close_system_tables(thd, backup); + + DBUG_RETURN(TRUE); +} + + /* Close system tables, opened with open_system_tables_for_read(). diff --git a/sql/sql_class.h b/sql/sql_class.h index da82ed5beed..8236239be3e 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -458,6 +458,7 @@ struct system_variables ulong optimizer_search_depth; /* A bitmap for switching optimizations on/off */ ulong optimizer_switch; + ulong optimizer_use_stat_tables; ulong preload_buff_size; ulong profiling_history_size; ulong query_cache_type; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc new file mode 100644 index 00000000000..b11d925a593 --- /dev/null +++ b/sql/sql_statistics.cc @@ -0,0 +1,1587 @@ +/* Copyright (C) 2009 MySQL AB + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA 02111-1307 USA */ + +/** + @file + + @brief + functions to update persitent statistical tables and to read from them + + @defgroup Query_Optimizer Query Optimizer + @{ +*/ + +#include "mysql_priv.h" +#include "sql_statistics.h" + +/* + The system variable 'optimizer_use_stat_tables' can take one of the + following values: + "never", "complementary", "preferably", "exclusively". + If the values of the variable 'optimizer_use_stat_tables' is set to + "never then any statistical data from the persistent statistical tables + is ignored by the optimizer. + If the value of the variable 'optimizer_use_stat_tables' is set to + "complementary" then a particular statistical characteristic is used + by the optimizer only if the database engine does not provide similar + statistics. For example, 'nulls_ratio' for table columns currently + are not provided by any engine. So optimizer uses this statistical data + from the statistical tables. At the same time it does not use + 'avg_frequency' for any index prefix from the statistical tables since + the a similar statistical characteristic 'records_per_key' can be + requested from the database engine. + If the value the variable 'optimizer_use_stat_tables' is set to + "preferably" the optimizer uses a particular statistical data only if + it can't be found in the statistical data. + If the value of the variable 'optimizer_use_stat_tables' is set to + "exclusively" the optimizer never uses statistical data that can be + returned by the database engine Only statistical data from the + statistical tables is used. + If an ANALYZE command is executed then it results in collecting + statistical data for the tables specified by the command and storing + the collected statistics in the persistent statistical tables only + when the value of the variable 'optimizer_use_stat_tables' is not + equal to "never". +*/ + +const char *optimizer_use_stat_tables_modes[] = + {"never", "complentary", "preferably", "exclusively", NullS}; + +TYPELIB optimizer_use_stat_tables_typelib= { + array_elements(optimizer_use_stat_tables_modes) - 1, "", + optimizer_use_stat_tables_modes, NULL +}; + +/* Currently there are only 3 persistent statistical tables */ +static const uint STATISTICS_TABLES= 3; + +/* + The names of the statistical tables in this list must correspond the + definitions of the tables in the file ../scripts/mysql_system_tables.sql +*/ +static const char *STAT_TABLE_NAME[STATISTICS_TABLES]= +{ + "table_stat", + "column_stat", + "index_stat" +}; + +/* + @details + The function sets null bits stored in the bitmap table_field->write_stat + for all statistical values collected for a column. +*/ +inline void set_nulls_for_write_column_stat_values(Field *table_field) +{ + table_field->write_stat.column_stat_nulls= + ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << + (COLUMN_STAT_COLUMN_NAME+1); +} + +/* + @details + The function sets null bits stored in the bitmap table_field->read_stat + for all statistical values collected for a column. +*/ +inline void set_nulls_for_read_column_stat_values(Field *table_field) +{ + table_field->read_stat.column_stat_nulls= + ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << + (COLUMN_STAT_COLUMN_NAME+1); +} + +/* + @details + The function removes the null bit stored in the bitmap + table_field->write_stat for the statistical value collected + on the statistical column number stat_field_no. +*/ +inline void set_not_null_for_write_column_stat_value(Field *table_field, + uint stat_field_no) +{ + table_field->write_stat.column_stat_nulls&= ~(1 << stat_field_no); +} + +/* + @details + The function removes the null bit stored in the bitmap + table_field->read_stat for the statistical value collected + on the statistical column number stat_field_no. +*/ +inline void set_not_null_for_read_column_stat_value(Field *table_field, + uint stat_field_no) +{ + table_field->read_stat.column_stat_nulls&= ~(1 << stat_field_no); +} + +/* + @details + The function checks the null bit stored in the bitmap + table_field->read_stat for the statistical value collected + on the statistical column number stat_field_no. +*/ +inline bool check_null_for_write_column_stat_value(Field *table_field, + uint stat_field_no) +{ + return table_field->write_stat.column_stat_nulls & (1 << stat_field_no); +} + +/* + Stat_table is the base class for classes Table_stat, Column_stat and + Index_stat. The methods of these classes allow us table to read + statistical data from statistical tables and write collected statistical + data into statistical data. Objects of the classes Table_stat, Column_stat + and Index stat are used for reading/writing statistics from/into + persistent tables table_stat, column_stat and index_stat correspondingly. + These tables are stored in the system database 'mysql'. + + Statistics is read and written always for a given database table t. When + an object of any of these classes is created a pointer to the TABLE + structure for this database table is passed as a parameter to the constructor + of the object. The other parameter is a pointer to the TABLE structure for + the corresponding statistical table st. So construction of an object to + read/write statistical data on table t from/into statistical table st + requires both table t and st to be opened. + + Reading/writing statistical data from/into a statistical table is always + performed by key. At the moment there is only one key defined for each + statistical table and this key is primary. + The primary key for the table table_stat is built as (db_name, table_name). + The primary key for the table column_stat is built as (db_name, table_name, + column_name). + The primary key for the table index_stat is built as (db_name, table_name, + index_name, prefix_arity). + + Reading statistical data from a statistical table is performed by the + following pattern. First a table dependent method sets the values of the + the fields that comprise the lookup key. Then an implementation of the + method get_stat_values() declared in Stat_table as a pure virtual method + finds the row from the statistical table by the set key. If the row is + found the values of statistical fields are read from this row and are + distributed in the internal structures. + + Let's assume the statistical data is read for table t from database db. + + When statistical data is searched in the table table_stat first + Table_stat::set_key_fields() should set the fields of db_name and + table_name. Then get_stat_values looks for a row by the set key value, + and, if the row is found, reads the value from the column + table_stat.cardinality into the field read_stat.cardinality of the TABLE + structure for table t and sets the value of read_stat.cardinality_is_null + from this structure to FALSE. If the value of the 'cardinality' column + in the row is null or if no row is found read_stat.cardinality_is_null + is set to TRUE. + + When statistical data is searched in the table column_stat first + Column_stat::set_key_fields() should set the fields of db_name, table_name + and column_name with column_name taken out of the only parameter f of the + Field* type passed to this method. After this get_stat_values looks + for a row by the set key value. If the row is found the values of statistical + data columns min_value, max_value, nulls_ratio, avg_length, avg_frequency + are read into internal structures. Values of nulls_ratio, avg_length, + avg_frequency are read into the corresponding fields of the read_stat + structure from the Field object f, while values from min_value and max_value + are copied into the min_value and max_value record buffers attached to the + TABLE structure for table t. + If the value of a statistical column in the found row is null, then the + corresponding flag in the f->read_stat.column_stat_nulls bitmap is set off. + Otherwise the flag is set on. If no row is found for the column the all flags + in f->column_stat_nulls are set off. + + When statistical data is searched in the table index_stat first + Index_stat::set_key_fields() has to be called to set the fields of db_name, + table_name, index_name and prefix_arity. The value of index_name is extracted + from the first parameter key_info of the KEY* type passed to the method. + This parameter specifies the index of interest idx. The second parameter + passed to the method specifies the arity k of the index prefix for which + statistical data is to be read. E.g. if the index idx consists of 3 + components (p1,p2,p3) the table index_stat usually will contain 3 rows for + this index: the first - for the prefix (p1), the second - for the prefix + (p1,p2), and the third - for the the prefix (p1,p2,p3). After the key fields + has been set a call of get_stat_value looks for a row by the set key value. + If the row is found and the value of the avg_frequency column is not null + then this value is assigned to key_info->read_stat.avg_frequency[k]. + Otherwise 0 is assigned to this element. + + The method Stat_table::update_stat is used to write statistical data + collected in the internal structures into a statistical table st. + It is assumed that before any invocation of this method a call of the + function st.set_key_fields has set the values of the primary key fields + that serve to locate the row from the statistical table st where the + the colected statistical data from internal structures are to be written + to. The statistical data is written from the counterparts of the + statistical fields of internal structures into which it would be read + by the functions get_stat_values. The counterpart fields are used + only when statistics is collected + When updating/inserting a row from the statistical table st the method + Stat_table::update_stat calls the implementation of the pure virtual + method store_field_values to transfer statistical data from the fields + of internal structures to the fields of record buffer used for updates + of the statistical table st. +*/ + +class Stat_table +{ +private: + /* Handler used for the retrieval of the statistical table stat_table */ + handler *stat_file; + + KEY *stat_key_info; /* Structure for the index to access stat_table */ + uint stat_key_length; /* Length of the key to access stat_table */ + uchar *record[2]; /* Record buffers used to access/update stat_table */ + uint stat_key_idx; /* The number of the key to access stat_table */ + +protected: + /* Statistical table to read statistics from or to update */ + TABLE *stat_table; + + /* Table for which statistical data is read / updated */ + TABLE *table; + char *db_name; /* Name of the database containing 'table' */ + uint db_name_len; /* Length of db_name */ + char *table_name; /* Name of the table 'table' */ + uint table_name_len; /* Name of table_name */ + +public: + + /* + @details + This constructor has to be called by any constructor of the derived + classes. The constructor 'tunes' the private and protected members of + the constructed object to the statistical table 'stat_table' with the + statistical data of our interest and to the table 'tab' for which this + statistics has been collected. + */ + Stat_table(TABLE *stat, TABLE *tab) :stat_table(stat), table(tab) + { + stat_file= stat_table->file; + /* Currently any statistical table has only one key */ + stat_key_idx= 0; + stat_key_info= &stat_table->key_info[stat_key_idx]; + stat_key_length= stat_key_info->key_length; + record[0]= stat_table->record[0]; + record[1]= stat_table->record[1]; + db_name= table->s->db.str; + db_name_len= table->s->db.length; + table_name= table->s->table_name.str; + table_name_len= table->s->table_name.length; + } + + virtual ~Stat_table() {} + + /* + @brief + Store statistical data into fields of the statistical table + + @details + This is a purely virtual method. + The implementation for any derived class shall put the appropriate + statistical data into the corresponding fields of stat_table. + + @note + The method is called by the update_stat function. + */ + virtual void store_stat_fields()= 0; + + /* + @brief + Read statistical data from fields of the statistical table + + @details + This is a purely virtual method. + The implementation for any derived read shall read the appropriate + statistical data from the corresponding fields of stat_table. + */ + virtual void get_stat_values()= 0; + + /* + @breif + Find a record by key in the statistical table + + @details + The function looks for a record in stat_table by its primary key. + It assumes that the key fields have been already stored in the record + buffer of stat_table. + + @retval + FALSE the record is not found + @retval + TRUE the record is found + */ + bool find_stat() + { + uchar key[MAX_KEY_LENGTH]; + key_copy(key, record[0], stat_key_info, stat_key_length); + return !stat_file->ha_index_read_idx_map(record[0], stat_key_idx, key, + HA_WHOLE_KEY, HA_READ_KEY_EXACT); + } + + /* + @breif + Update/insert a record in the statistical table with new statistics + + @details + The function first looks for a record by its primary key in the statistical + table stat_table. If the record is found the function updates statistical + fields of the records. The data for these fields are taken from internal + structures containing info on the table 'table'. If the record is not + found the function inserts a new record with the primary key set to the + search key and the statistical data taken from the internal structures. + The function assumes that the key fields have been already stored in + the record buffer of stat_table. + + @retval + FALSE success with the update/insert of the record + @retval + TRUE failure with the update/insert of the record + + @note + The function calls the virtual method store_stat_fields to populate the + statistical fields of the updated/inserted row with new statistics. + */ + bool update_stat() + { + int err; + if (find_stat()) + { + store_record(stat_table, record[1]); + store_stat_fields(); + if ((err= stat_file->ha_update_row(record[1], record[0])) && + err != HA_ERR_RECORD_IS_THE_SAME) + return TRUE; + } + else + { + store_stat_fields(); + if ((err= stat_file->ha_write_row(record[0]))) + return TRUE; + } + return FALSE; + } +}; + + +/* + An object of the class Table_stat is created to read statistical + data on tables from the statistical table table_stat or to update + table_stat with such statistical data. + Rows from the statistical table are read and updated always by + primary key. +*/ + +class Table_stat: public Stat_table +{ +private: + Field *db_name_field; /* Field for the column table_stat.db_name */ + Field *table_name_field; /* Field for the column table_stat.table_name */ + +public: + + /* + @details + The constructor 'tunes' the private and protected members of the + constructed object for the statistical table table_stat to read/update + statistics on table 'tab'. The TABLE structure for the table table_stat + must be passed as a value for the parameter 'stat'. + */ + Table_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + { + db_name_field= stat_table->field[TABLE_STAT_DB_NAME]; + table_name_field= stat_table->field[TABLE_STAT_TABLE_NAME]; + } + + /* + @brief + Set the key fields for the statistical table table_stat + + @details + The function sets the values of the fields db_name and table_name + in the record buffer for the statistical table table_stat. + These fields comprise the primary key for the table. + + @note + The function is supposed to be called before any use of the + method find_stat for an object of the Table_stat class. + */ + void set_key_fields() + { + db_name_field->store(db_name, db_name_len, &my_charset_bin); + table_name_field->store(table_name, table_name_len, &my_charset_bin); + } + + /* + @brief + Store statistical data into statistical fields of table_stat + + @details + This implementation of a purely virtual method sets the value of the + column 'cardinality' of the statistical table table_stat according to + the value of the flag write_stat.cardinality_is_null and the value of + the field write_stat.cardinality' from the TABLE structure for 'table'. + */ + void store_stat_fields() + { + Field *stat_field= stat_table->field[TABLE_STAT_CARDINALITY]; + if (table->write_stat.cardinality_is_null) + stat_field->set_null(); + else + { + stat_field->set_notnull(); + stat_field->store(table->write_stat.cardinality); + } + } + + /* + @brief + Read statistical data from statistical fields of table_stat + + @details + This implementation of a purely virtual method first looks for a record + the statistical table table_stat by its primary key set the record + buffer with the help of Table_stat::set_key_fields. Then, if the row is + found the function reads the value of the column 'cardinality' of the table + table_stat and sets the value of the flag read_stat.cardinality_is_null + and the value of the field read_stat.cardinality' from the TABLE structure + for 'table' accordingly. + */ + void get_stat_values() + { + table->read_stat.cardinality_is_null= TRUE; + table->read_stat.cardinality= 0; + if (find_stat()) + { + Field *stat_field= stat_table->field[TABLE_STAT_CARDINALITY]; + if (!stat_field->is_null()) + { + table->read_stat.cardinality_is_null= FALSE; + table->read_stat.cardinality= stat_field->val_int(); + } + } + } + +}; + + +/* + An object of the class Column_stat is created to read statistical data + on table columns from the statistical table column_stat or to update + column_stat with such statistical data. + Rows from the statistical table are read and updated always by + primary key. +*/ + +class Column_stat: public Stat_table +{ +private: + Field *db_name_field; /* Field for the column column_stat.db_name */ + Field *table_name_field; /* Field for the column column_stat.table_name */ + Field *column_name_field; /* Field for the column column_stat.column_name */ + + Field *table_field; /* Field from 'table' to read /update statistics on */ + +public: + + /* + @details + The constructor 'tunes' the private and protected members of the + constructed object for the statistical table column_stat to read/update + statistics on fields of the table 'tab'. The TABLE structure for the table + column_stat must be passed as a value for the parameter 'stat'. + */ + Column_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + { + db_name_field= stat_table->field[COLUMN_STAT_DB_NAME]; + table_name_field= stat_table->field[COLUMN_STAT_TABLE_NAME]; + column_name_field= stat_table->field[COLUMN_STAT_COLUMN_NAME]; + } + + /* + @brief + Set the key fields for the statistical table column_stat + + @param + column Field for the 'table' column to read/update statistics on + + @details + The function sets the values of the fields db_name, table_name and + column_name in the record buffer for the statistical table column_stat. + These fields comprise the primary key for the table. + + @note + The function is supposed to be called before any use of the + method find_stat for an object of the Column_stat class. + */ + void set_key_fields(Field *column) + { + db_name_field->store(db_name, db_name_len, &my_charset_bin); + table_name_field->store(table_name, table_name_len, &my_charset_bin); + table_field= column; + const char *column_name= column->field_name; + column_name_field->store(column_name, strlen(column_name), &my_charset_bin); + } + + /* + @brief + Store statistical data into statistical fields of column_stat + + @details + This implementation of a purely virtual method sets the value of the + columns 'min_value', 'max_value', 'nulls_ratio', 'avg_length' and + 'avg_frequency' of the stistical table columns_stat according to the + contents of the bitmap write_stat.column_stat_nulls and the values + of the fields min_value, max_value, nulls_ratio, avg_length and + avg_frequency of the structure write_stat from the Field structure + for the field 'table_field'. + The value of the k-th column in the table columns_stat is set to NULL + if the k-th bit in the bitmap 'column_stat_nulls' is set to 1. + + @note + A value from the field min_value/max_value is always converted + into a utf8 string. If the length of the column 'min_value'/'max_value' + is less than the length of the string the string is trimmed to fit the + length of the column. + */ + void store_stat_fields() + { + char buff[MAX_FIELD_WIDTH]; + String val(buff, sizeof(buff), &my_charset_utf8_bin); + + for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_AVG_FREQUENCY; i++) + { + Field *stat_field= stat_table->field[i]; + if (check_null_for_write_column_stat_value(table_field, i)) + stat_field->set_null(); + else + { + stat_field->set_notnull(); + switch (i) { + case COLUMN_STAT_MIN_VALUE: + if (table_field->type() == MYSQL_TYPE_BIT) + stat_field->store(table_field->write_stat.min_value->val_int()); + else + { + table_field->write_stat.min_value->val_str(&val); + stat_field->store(val.ptr(), val.length(), &my_charset_utf8_bin); + } + break; + case COLUMN_STAT_MAX_VALUE: + if (table_field->type() == MYSQL_TYPE_BIT) + stat_field->store(table_field->write_stat.max_value->val_int()); + else + { + table_field->write_stat.max_value->val_str(&val); + stat_field->store(val.ptr(), val.length(), &my_charset_utf8_bin); + } + break; + case COLUMN_STAT_NULLS_RATIO: + stat_field->store(table_field->write_stat.nulls_ratio); + break; + case COLUMN_STAT_AVG_LENGTH: + stat_field->store(table_field->write_stat.avg_length); + break; + case COLUMN_STAT_AVG_FREQUENCY: + stat_field->store(table_field->write_stat.avg_frequency); + break; + } + } + } + } + + /* + @brief + Read statistical data from statistical fields of column_stat + + @details + This implementation of a purely virtual method first looks for a record + the statistical table column_stat by its primary key set the record + buffer with the help of Column_stat::set_key_fields. Then, if the row is + found, the function reads the values of the columns 'min_value', + 'max_value', 'nulls_ratio', 'avg_length' and 'avg_frequency' of the + table column_stat and sets accordingly the value of the bitmap + read_stat.column_stat_nulls' and the values of the fields min_value, + max_value, nulls_ratio, avg_length and avg_frequency of the structure + read_stat from the Field structure for the field 'table_field'. + */ + void get_stat_values() + { + set_nulls_for_read_column_stat_values(table_field); + + if (table_field->read_stat.min_value) + table_field->read_stat.min_value->set_null(); + if (table_field->read_stat.max_value) + table_field->read_stat.max_value->set_null(); + + if (find_stat()) + { + char buff[MAX_FIELD_WIDTH]; + String val(buff, sizeof(buff), &my_charset_utf8_bin); + + for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_AVG_FREQUENCY; i++) + { + Field *stat_field= stat_table->field[i]; + + if (!stat_field->is_null() && + (i > COLUMN_STAT_MAX_VALUE || + (i == COLUMN_STAT_MIN_VALUE && table_field->read_stat.min_value) || + (i == COLUMN_STAT_MAX_VALUE && table_field->read_stat.max_value))) + { + set_not_null_for_read_column_stat_value(table_field, i); + + switch (i) { + case COLUMN_STAT_MIN_VALUE: + stat_field->val_str(&val); + table_field->read_stat.min_value->store(val.ptr(), val.length(), + &my_charset_utf8_bin); + break; + case COLUMN_STAT_MAX_VALUE: + stat_field->val_str(&val); + table_field->read_stat.max_value->store(val.ptr(), val.length(), + &my_charset_utf8_bin); + break; + case COLUMN_STAT_NULLS_RATIO: + table_field->read_stat.nulls_ratio= stat_field->val_real(); + break; + case COLUMN_STAT_AVG_LENGTH: + table_field->read_stat.avg_length= stat_field->val_real(); + break; + case COLUMN_STAT_AVG_FREQUENCY: + table_field->read_stat.avg_frequency= stat_field->val_real(); + break; + } + } + } + } + } + +}; + + +/* + An object of the class Index_stat is created to read statistical + data on index prefixes from the statistical table index_stat or + to update index_stat with such statistical data. + Rows from the statistical table are read and updated always by + primary key. +*/ + +class Index_stat: public Stat_table +{ +private: + Field *db_name_field; /* Field for the column index_stat.db_name */ + Field *table_name_field; /* Field for the column index_stat.table_name */ + Field *index_name_field; /* Field for the column index_stat.table_name */ + Field *prefix_arity_field; /* Field for the column index_stat.prefix_arity */ + + KEY *table_key_info; /* Info on the index to read/update statistics on */ + uint prefix_arity; /* Number of components of the index prefix of interest */ + +public: + + /* + @details + The constructor 'tunes' the private and protected members of the + constructed object for the statistical table index_stat to read/update + statistics on prefixes of different indexes of the table 'tab'. + The TABLE structure for the table index_stat must be passed as a value + for the parameter 'stat'. + */ + Index_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + { + db_name_field= stat_table->field[INDEX_STAT_DB_NAME]; + table_name_field= stat_table->field[INDEX_STAT_TABLE_NAME]; + index_name_field= stat_table->field[INDEX_STAT_INDEX_NAME]; + prefix_arity_field= stat_table->field[INDEX_STAT_PREFIX_ARITY]; + + } + + /* + @brief + Set the key fields for the statistical table index_stat + + @param + index_info Info for the index of 'table' to read/update statistics on + @param + index_prefix_arity Number of components in the index prefix of interest + + + @details + The function sets the values of the fields db_name, table_name and + index_name, prefix_arity in the record buffer for the statistical + table index_stat. These fields comprise the primary key for the table. + + @note + The function is supposed to be called before any use of the + method find_stat for an object of the Index_stat class. + */ + void set_key_fields(KEY *index_info, uint index_prefix_arity) + { + db_name_field->store(db_name, db_name_len, &my_charset_bin); + table_name_field->store(table_name, table_name_len, &my_charset_bin); + table_key_info= index_info; + char *index_name= index_info->name; + index_name_field->store(index_name, strlen(index_name), &my_charset_bin); + prefix_arity= index_prefix_arity; + prefix_arity_field->store(index_prefix_arity, TRUE); + } + + /* + @brief + Store statistical data into statistical fields of tableindex_stat + + @details + This implementation of a purely virtual method sets the value of the + column 'avg_frequency' of the statistical table index_stat according to + the value of write_stat.avg_frequency[Index_stat::prefix_arity] + from the KEY_INFO structure 'table_key_info'. + If the value of write_stat. avg_frequency[Index_stat::prefix_arity] is + equal to 0, the value of the column is set to NULL. + */ + void store_stat_fields() + { + Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; + double avg_frequency= + table_key_info->write_stat.avg_frequency[prefix_arity-1]; + if (avg_frequency == 0) + stat_field->set_null(); + else + { + stat_field->set_notnull(); + stat_field->store(avg_frequency); + } + } + + /* + @brief + Read statistical data from statistical fields of index_stat + + @details + This implementation of a purely virtual method first looks for a record the + statistical table index_stat by its primary key set the record buffer with + the help of Index_stat::set_key_fields. If the row is found the function + reads the value of the column 'avg_freguency' of the table index_stat and + sets the value of read_stat.avg_frequency[Index_stat::prefix_arity] + from the KEY_INFO structure 'table_key_info' accordingly. If the value of + the column is NULL, read_stat.avg_frequency[Index_stat::prefix_arity] is + set to 0. Otherwise, read_stat.avg_frequency[Index_stat::prefix_arity] is + set to the value of the column. + */ + void get_stat_values() + { + double avg_frequency= 0; + if(find_stat()) + { + Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; + if (!stat_field->is_null()) + avg_frequency= stat_field->val_real(); + } + table_key_info->read_stat.avg_frequency[prefix_arity-1]= avg_frequency; + } + +}; + + +/* + The class Count_distinct_field is a helper class used to calculate + the number of distinct values for a column. The class employs the + Unique class for this purpose. + The class Count_distinct_field is used only by the function + collect_statistics_from_table to calculate the values for + column avg_frequency of the statistical table column_stat. +*/ + +class Count_distinct_field: public Sql_alloc +{ +protected: + + /* Field for which the number of distinct values is to be find out */ + Field *table_field; + Unique *tree; /* The helper object to contain distinct values */ + uint tree_key_length; /* The length of the keys for the elements of 'tree */ + +public: + + /* + @param + field Field for which the number of distinct values is + to be find out + @param + max_heap_table_size The linit for the memory used by the RB tree container + of the constructed Unique object 'tree' + + @details + The constructor sets the values of 'table_field' and 'tree_key_length', + and then calls the 'new' operation to create a Unique object for 'tree'. + The type of 'field' and the value max_heap_table_size of determine the set + of the parameters to be passed to the constructor of the Unique object. + */ + Count_distinct_field(Field *field, uint max_heap_table_size) + { + qsort_cmp2 compare_key; + void* cmp_arg; + enum enum_field_types f_type= field->type(); + + table_field= field; + tree_key_length= field->pack_length(); + + if ((f_type == MYSQL_TYPE_VARCHAR) || + (!field->binary() && (f_type == MYSQL_TYPE_STRING || + f_type == MYSQL_TYPE_VAR_STRING))) + { + compare_key= (qsort_cmp2) simple_str_key_cmp; + cmp_arg= (void*) field; + } + else + { + cmp_arg= (void*) &tree_key_length; + compare_key= (qsort_cmp2) simple_raw_key_cmp; + } + + tree= new Unique(compare_key, cmp_arg, + tree_key_length, max_heap_table_size); + } + + virtual ~Count_distinct_field() + { + delete tree; + tree= NULL; + } + + /* + @brief + Check whether the Unique object tree has been succesfully created + */ + bool exists() + { + return (tree != NULL); + } + + /* + @brief + Add the value of 'field' to the container of the Unique object 'tree' + */ + virtual bool add() + { + return tree->unique_add(table_field->ptr); + } + + /* + @brief + Calculate the number of elements accumulated in the container of 'tree' + */ + ulonglong get_value() + { + ulonglong count; + if (tree->elements == 0) + return (ulonglong) tree->elements_in_tree(); + count= 0; + tree->walk(count_distinct_walk, (void*) &count); + return count; + } +}; + + +/* + The class Count_distinct_field_bit is derived from the class + Count_distinct_field to be used only for fields of the MYSQL_TYPE_BIT type. + The class provides a different implementation for the method add +*/ + +class Count_distinct_field_bit: public Count_distinct_field +{ +public: + Count_distinct_field_bit(Field *field, uint max_heap_table_size) + :Count_distinct_field(field, max_heap_table_size) {} + bool add() + { + longlong val= table_field->val_int(); + return tree->unique_add(&val); + } +}; + + +/* + The class Index_prefix_calc is a helper class used to calculate the values + for the column 'avg_frequency' of the statistical table index_stat. + For any table t from the database db and any k-component prefix of the + index i for this table the row from index_stat with the primary key + (db,t,i,k) must contain in the column 'avg_frequency' either NULL or + the number that is the ratio of N and V, where N is the number of index + entries without NULL values in the first k components of the index i, + and V is the number of distinct tuples composed of the first k components + encountered among these index entries. + Currently the objects of this class are used only by the function + collect_statistics_for_index. +*/ + +class Index_prefix_calc: public Sql_alloc +{ +private: + /* Table containing index specified by index_info */ + TABLE *index_table; + /* Info for the index i for whose prefix 'avg_frequency' is calculated */ + KEY *index_info; + /* The maximum number of the components in the prefixes of interest */ + uint prefixes; + bool empty; + + /* This structure is created for every k components of the index i */ + class Prefix_calc_state + { + public: + /* + The number of the scanned index entries without nulls + in the first k components + */ + ulonglong entry_count; + /* + The number if the scanned index entries without nulls with + the last encountered k-component prefix + */ + ulonglong prefix_count; + /* The values of the last encoutered k-component prefix */ + Cached_item *last_prefix; + }; + + /* + Array of structures used to calculate 'avg_frequency' for different + prefixes of the index i + */ + Prefix_calc_state *calc_state; + +public: + Index_prefix_calc(TABLE *table, KEY *key_info) + : index_table(table), index_info(key_info) + { + uint i; + Prefix_calc_state *state; + uint key_parts= key_info->key_parts; + empty= TRUE; + prefixes= 0; + if ((calc_state= + (Prefix_calc_state *) sql_alloc(sizeof(Prefix_calc_state)*key_parts))) + { + uint keyno= key_info-table->key_info; + for (i= 0, state= calc_state; i < key_parts; i++, state++) + { + /* + Do not consider prefixes containing a component that is only part + of the field. This limitation is set to avoid fetching data when + calculating the values of 'avg_frequency' for prefixes. + */ + if (!key_info->key_part[i].field->part_of_key.is_set(keyno)) + break; + + if (!(state->last_prefix= + new Cached_item_field(key_info->key_part[i].field))) + break; + state->entry_count= state->prefix_count= 0; + prefixes++; + } + } + } + + /* + @breif + Change the elements of calc_state after reading the next index entry + + @details + This function is to be called at the index scan each time the next + index entry has been read into the record buffer. + For each of the index prefixes the function checks whether nulls + are encountered in any of the k components of the prefix. + If this is not the case the value of calc_state[k-1].entry_count + is incremented by 1. Then the function checks whether the value of + any of these k components has changed. If so, the value of + calc_state[k-1].prefix_count is incremented by 1. + */ + void add() + { + uint i; + Prefix_calc_state *state; + uint first_changed= prefixes; + for (i= prefixes, state= calc_state+prefixes-1; i; i--, state--) + { + if (state->last_prefix->cmp()) + first_changed= i-1; + } + if (empty) + { + first_changed= 0; + empty= FALSE; + } + for (i= 0, state= calc_state; i < prefixes; i++, state++) + { + if (state->last_prefix->null_value) + break; + if (i >= first_changed) + state->prefix_count++; + state->entry_count++; + } + } + + /* + @brief + Calculate the values of avg_frequency for all prefixes of an index + + @details + This function is to be called after the index scan to count the number + of distinct index prefixes has been done. The function calculates + the value of avg_frequency for the index prefix with k components + as calc_state[k-1].entry_count/calc_state[k-1].prefix_count. + If calc_state[k-1].prefix_count happens to be 0, the value of + avg_frequency[k-1] is set to 0, i.e. is considered as unknown. + */ + void get_avg_frequency() + { + uint i; + Prefix_calc_state *state; + for (i= 0, state= calc_state; i < prefixes; i++, state++) + { + if (i < prefixes) + { + index_info->write_stat.avg_frequency[i]= + state->prefix_count == 0 ? 0 : + (double) state->entry_count / state->prefix_count; + } + } + } +}; + + +/* + @brief + Create fields for min/max values to collect/read column statistics + + @param + table Table the fields are created for + @param + for_write Those fields are created that are used to collect statistics + + @note + The function first allocates record buffers to store min/max values + for 'table's fields. Then for each table field f it creates Field structures + that points to these buffers rather that to the record buffer as the + Field object for f does. The pointers of the created fields are placed + either in the write_stat or in the read_stat structure of the Field + object for f, depending on the value of the 'for_write' parameter. + + @note + The buffers allocated when min/max values are used to read statistics + from the persistent statistical tables differ from those buffers that + are used when statistics on min/max values for column is collected. + The same is true for the fields created for min/max values. +*/ + +static +void create_min_max_stistical_fields(TABLE *table, bool for_write) +{ + Field *table_field; + Field **field_ptr; + uchar *record; + uint rec_buff_length= table->s->rec_buff_length; + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + if (for_write) + table_field->write_stat.max_value= + table_field->write_stat.min_value= NULL; + else + table_field->read_stat.max_value= + table_field->read_stat.min_value= NULL; + } + + if ((record= (uchar *) alloc_root(&table->mem_root, 2*rec_buff_length))) + { + for (uint i=0; i < 2; i++, record+= rec_buff_length) + { + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + Field *fld; + table_field= *field_ptr; + my_ptrdiff_t diff= record-table->record[0]; + if (!(fld= table_field->clone(&table->mem_root, table, diff, TRUE))) + continue; + if (i == 0) + { + if (for_write) + table_field->write_stat.min_value= fld; + else + table_field->read_stat.min_value= fld; + } + else + { + if (for_write) + table_field->write_stat.max_value= fld; + else + table_field->read_stat.max_value= fld; + } + } + } + } +} + +/* + @brief + Collect statistical data on an index + + @param + table The table the index belongs to + index The number of this index in the table + + @details + The function collects the value of 'avg_frequency' for the prefixes + on an index from 'table'. The index is specified by its number. + If the scan is successful the calculated statistics is saved in the + elements of the array write_stat.avg_frequency of the KEY_INFO structure + for the index. The statistics for the prefix with k components is saved + in the element number k-1. + + @retval + 0 If the statistics has been successfully collected + @retval + 1 Otherwise + + @note + The function collects statistics for the index prefixes for one index + scan during which no data is fetched from the table records. That's why + statistical data for prefixes that contain part of a field is not + collected. + The function employs an object of the helper class Index_prefix_calc to + count for each index prefix the number of index entries without nulls and + the number of distinct entries among them. + +*/ + +static +int collect_statistics_for_index(TABLE *table, uint index) +{ + int rc= 0; + KEY *key_info= &table->key_info[index]; + ha_rows rows= 0; + Index_prefix_calc index_prefix_calc(table, key_info); + DBUG_ENTER("collect_statistics_for_index"); + + table->key_read= 1; + table->file->extra(HA_EXTRA_KEYREAD); + + table->file->ha_index_init(index, TRUE); + rc= table->file->ha_index_first(table->record[0]); + while (rc != HA_ERR_END_OF_FILE) + { + if (rc) + break; + rows++; + index_prefix_calc.add(); + rc= table->file->ha_index_next(table->record[0]); + } + table->key_read= 0; + table->file->ha_index_end(); + + rc= (rc == HA_ERR_END_OF_FILE) ? 0 : 1; + + if (!rc) + index_prefix_calc.get_avg_frequency(); + + DBUG_RETURN(rc); +} + +/* + @brief + Collect statistical data for a table + + @param + thd The thread handle + @param + table The table to collect statistics on + + @details + The function collects data for various statistical characteristics on + the table 'table'. These data is saved in the internal fields that could + be reached from 'table'. The data is prepared to be saved in the persistent + statistical table by the function update_statistics_for_table. + The collected statistical values are not placed in the same fields that + keep the statistical data used by the optimizer. Therefore, at any time, + there is no collision between the statistics being collected and the one + used by the optimizer to look for optimal query execution plans for other + clients. + + @retval + 0 If the statistics has been successfully collected + @retval + 1 Otherwise + + @note + The function first collects statistical data for statistical characteristics + to be saved in the statistical tables table_stat and column_stat. To do this + it performs a full table scan of 'table'. At this scan the function collects + statistics on each column of the table and count the total number of the + scanned rows. To calculate the value of 'avg_frequency' for a column the + function constructs an object of the helper class Count_distinct_field + (or its derivation). Currently this class cannot count the number of + distinct values for blob columns. So the value of 'avg_frequency' for + blob columns is always null. + After the full table scan the function calls collect_statistics_for_index + for each table index. The latter performs full index scan for each index. + + @note + Currently the statistical data is collected indiscriminately for all + columns/indexes of 'table', for all statistical characteristics. + TODO. Collect only specified statistical characteristics for specified + columns/indexes. + + @note + Currently the process of collecting statistical data is not optimized. + For example, 'avg_frequency' for a column could be copied from the + 'avg_frequency' collected for an index if this column is used as the + first component of the index. Min and min values for this column could + be extracted from the index as well. +*/ + +int collect_statistics_for_table(THD *thd, TABLE *table) +{ + int rc; + Field **field_ptr; + Field *table_field; + ha_rows rows= 0; + handler *file=table->file; + + DBUG_ENTER("collect_statistics_for_table"); + + table->write_stat.cardinality_is_null= TRUE; + table->write_stat.cardinality= 0; + + create_min_max_stistical_fields(table, TRUE); + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + uint max_heap_table_size= thd->variables.max_heap_table_size; + set_nulls_for_write_column_stat_values(table_field); + table_field->nulls= 0; + table_field->column_total_length= 0; + if (table_field->flags & BLOB_FLAG) + table_field->count_distinct= NULL; + else + { + table_field->count_distinct= + table_field->type() == MYSQL_TYPE_BIT ? + new Count_distinct_field_bit(table_field, max_heap_table_size) : + new Count_distinct_field(table_field, max_heap_table_size); + } + if (table_field->count_distinct && + !table_field->count_distinct->exists()) + table_field->count_distinct= NULL; + } + + bitmap_set_all(table->read_set); + + /* Perform a full table scan to collect statistics on 'table's columns */ + if (!(rc= file->ha_rnd_init(FALSE))) + { + while ((rc= file->ha_rnd_next(table->record[0])) != HA_ERR_END_OF_FILE) + { + if (rc) + break; + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + if (table_field->is_null()) + table_field->nulls++; + else + { + table_field->column_total_length+= table_field->value_length(); + if (table_field->write_stat.min_value && + table_field->update_min(table_field->write_stat.min_value, + rows == table_field->nulls)) + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_MIN_VALUE); + if (table_field->write_stat.max_value && + table_field->update_max(table_field->write_stat.max_value, + rows == table_field->nulls)) + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_MAX_VALUE); + if (table_field->count_distinct) + table_field->count_distinct->add(); + } + } + rows++; + } + file->ha_rnd_end(); + } + rc= rc == HA_ERR_END_OF_FILE ? 0 : 1; + + /* + Calculate values for all statistical characteristics on columns and + and for each field f of 'table' save them in the write_stat structure + from the Field object for f. + */ + if (!rc) + { + table->write_stat.cardinality_is_null= FALSE; + table->write_stat.cardinality= rows; + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + table_field->write_stat.nulls_ratio= (double) table_field->nulls/rows; + table_field->write_stat.avg_length= + (double) table_field->column_total_length / (rows-table_field->nulls); + if (table_field->count_distinct) + { + table_field->write_stat.avg_frequency= + (double) (rows-table_field->nulls) / + table_field->count_distinct->get_value(); + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_AVG_FREQUENCY); + delete table_field->count_distinct; + table_field->count_distinct= NULL; + } + + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_NULLS_RATIO); + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_AVG_LENGTH); + } + } + + if (!rc) + { + uint keys= table->s->keys ; + + /* Collect statistics for indexes */ + for (uint i= 0; i < keys; i++) + { + if ((rc= collect_statistics_for_index(table, i))) + break; + } + } + + DBUG_RETURN(rc); +} + + +/* + @brief + Update statistics for a table in the persistent statistical tables + + @param + thd The thread handle + @param + table The table to collect statistics on + + @details + For each statistical table st the function looks for the rows from this + table that contain statistical data on 'table'. If rows with given + statistical characteritics exist they are updated with the new statistical + values taken from internal structures for 'table'. Otherwise new rows + with these statistical characteristics are added into st. + It is assumed that values stored in the statistical tables are found and + saved by the function collect_statistics_for_table. + + @retval + 0 If all statistical tables has been successfully updated + @retval + 1 Otherwise + + @note + The function is called when executing the ANALYZE actions for 'table'. + The function first unlocks the opened table the statistics on which has + been collected, but does not closes it, so all collected statistical data + remains in internal structures for 'table'. Then the function opens the + statistical tables and writes the statistical data for 'table'into them. + It is not allowed just to open statistical tables for writing when some + other tables are locked for reading. + After the statistical tables have been opened they are updated one by one + with the new statistics on 'table'. Objects of the helper classes + Table_stat, Column_stat and Index_stat are employed for this. + After having been updated the statistical system tables are closed. +*/ + +int update_statistics_for_table(THD *thd, TABLE *table) +{ + TABLE_LIST tables[STATISTICS_TABLES]; + Open_tables_state open_tables_state_backup; + uint i; + int err; + int rc= 0; + TABLE *stat_table; + uint keys= table->s->keys; + + DBUG_ENTER("update_statistics_for_table"); + + bzero((char *) &tables[0], sizeof(tables)); + + for (i= 0; i < STATISTICS_TABLES; i++) + { + tables[i].db= (char*) "mysql"; + tables[i].table_name= (char *) STAT_TABLE_NAME[i]; + tables[i].alias= tables[i].table_name; + tables[i].lock_type= TL_WRITE; + if (i < STATISTICS_TABLES - 1) + tables[i].next_global= tables[i].next_local= + tables[i].next_name_resolution_table= &tables[i+1]; + } + + if (unlock_tables_n_open_system_tables_for_write(thd, + tables, + &open_tables_state_backup)) + DBUG_RETURN(1); + + /* Update the statistical table table_stat */ + stat_table= tables[TABLE_STAT].table; + Table_stat table_stat(stat_table, table); + restore_record(stat_table, s->default_values); + table_stat.set_key_fields(); + err= table_stat.update_stat(); + if (err) + rc= 1; + + /* Update the statistical table colum_stat */ + stat_table= tables[COLUMN_STAT].table; + Column_stat column_stat(stat_table, table); + for (Field **field_ptr= table->field; *field_ptr; field_ptr++) + { + Field *table_field= *field_ptr; + restore_record(stat_table, s->default_values); + column_stat.set_key_fields(table_field); + err= column_stat.update_stat(); + if (err & !rc) + rc= 1; + } + + /* Update the statistical table index_stat */ + stat_table= tables[INDEX_STAT].table; + Index_stat index_stat(stat_table, table); + KEY *key_info, *key_info_end; + + for (key_info= table->key_info, key_info_end= table->key_info+keys; + key_info < key_info_end; key_info++) + { + uint key_parts= key_info->key_parts; + for (i= 0; i < key_parts; i++) + { + restore_record(stat_table, s->default_values); + index_stat.set_key_fields(key_info, i+1); + err= index_stat.update_stat(); + if (err & !rc) + rc= 1; + } + } + + close_system_tables(thd, &open_tables_state_backup); + + DBUG_RETURN(rc); +} + + +/* + @brief + Read statistics for a table from the persistent statistical tables + + @param + thd The thread handle + @param + table The table to read statistics on + + @details + For each statistical table the function looks for the rows from this + table that contain statistical data on 'table'. If such rows is found + the data from statistical columns of it is read into the appropriate + fields of internal structures for 'table'. Later at the query processing + this data are supposed to be used by the optimizer. + The function is called in function open_tables. + + @retval + 0 If data has been succesfully read from all statistical tables + @retval + 1 Otherwise + + @note + The function first calls the function open_system_tables_for_read to + be able to read info from the statistical tables. On success the data is + read from one table after another after which the statistical tables are + closed. Objects of the helper classes Table_stat, Column_stat and Index_stat + are employed to read statistical data from the statistical tables. + TODO. Consider a variant when statistical tables are opened and closed + only once for all tables, not for every table of the query as it's done + now. +*/ + +int read_statistics_for_table(THD *thd, struct st_table *table) +{ + uint i; + TABLE *stat_table; + Field *table_field; + Field **field_ptr; + KEY *key_info, *key_info_end; + TABLE_LIST tables[STATISTICS_TABLES]; + Open_tables_state open_tables_state_backup; + + DBUG_ENTER("read_statistics_for_table"); + + bzero((char *) &tables[0], sizeof(tables)); + + for (i= 0; i < STATISTICS_TABLES; i++) + { + tables[i].db= (char*) "mysql"; + tables[i].table_name= (char *) STAT_TABLE_NAME[i]; + tables[i].alias= tables[i].table_name; + tables[i].lock_type= TL_READ; + if (i < STATISTICS_TABLES - 1) + tables[i].next_global= tables[i].next_local= + tables[i].next_name_resolution_table= &tables[i+1]; + } + + if (open_system_tables_for_read(thd, tables, &open_tables_state_backup)) + DBUG_RETURN(1); + + create_min_max_stistical_fields(table, FALSE); + + /* Read statistics from the statistical table index_stat */ + stat_table= tables[TABLE_STAT].table; + Table_stat table_stat(stat_table, table); + table_stat.set_key_fields(); + table_stat.get_stat_values(); + + /* Read statistics from the statistical table column_stat */ + stat_table= tables[COLUMN_STAT].table; + Column_stat column_stat(stat_table, table); + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + column_stat.set_key_fields(table_field); + column_stat.get_stat_values(); + } + + /* Read statistics from the statistical table index_stat */ + stat_table= tables[INDEX_STAT].table; + Index_stat index_stat(stat_table, table); + for (key_info= table->key_info, key_info_end= key_info+table->s->keys; + key_info < key_info_end; key_info++) + { + + for (i= 0; i < key_info->key_parts; i++) + { + index_stat.set_key_fields(key_info, i+1); + index_stat.get_stat_values(); + } + } + + close_system_tables(thd, &open_tables_state_backup); + + DBUG_RETURN(0); +} diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h new file mode 100644 index 00000000000..1a8cbf6c3f3 --- /dev/null +++ b/sql/sql_statistics.h @@ -0,0 +1,63 @@ +/* Copyright 2006-2008 MySQL AB, 2008 Sun Microsystems, Inc. + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */ + +#ifndef SQL_STATISTICS_H +#define SQL_STATISTICS_H + +/* + These enumeration types comprise the dictionary of three + statistical tables table_stat, column_stat and index_stat + as they defined in ../scripts/mysql_system_tables.sql. + + It would be nice if the declarations of these types were + generated automatically by the table definitions. +*/ + +enum enum_stat_tables +{ + TABLE_STAT, + COLUMN_STAT, + INDEX_STAT, +}; + +enum enum_table_stat_col +{ + TABLE_STAT_DB_NAME, + TABLE_STAT_TABLE_NAME, + TABLE_STAT_CARDINALITY +}; + +enum enum_column_stat_col +{ + COLUMN_STAT_DB_NAME, + COLUMN_STAT_TABLE_NAME, + COLUMN_STAT_COLUMN_NAME, + COLUMN_STAT_MIN_VALUE, + COLUMN_STAT_MAX_VALUE, + COLUMN_STAT_NULLS_RATIO, + COLUMN_STAT_AVG_LENGTH, + COLUMN_STAT_AVG_FREQUENCY +}; + +enum enum_index_stat_col +{ + INDEX_STAT_DB_NAME, + INDEX_STAT_TABLE_NAME, + INDEX_STAT_INDEX_NAME, + INDEX_STAT_PREFIX_ARITY, + INDEX_STAT_AVG_FREQUENCY +}; + +#endif /* SQL_STATISTICS_H */ diff --git a/sql/sql_table.cc b/sql/sql_table.cc index be4c0e3e0d0..c057834bdcc 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -4692,6 +4692,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, Protocol *protocol= thd->protocol; LEX *lex= thd->lex; int result_code; + int compl_result_code; bool need_repair_or_alter= 0; DBUG_ENTER("mysql_admin_table"); DBUG_PRINT("enter", ("extra_open_options: %u", extra_open_options)); @@ -4946,9 +4947,22 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, } } - DBUG_PRINT("admin", ("calling operator_func '%s'", operator_name)); - result_code = (table->table->file->*operator_func)(thd, check_opt); - DBUG_PRINT("admin", ("operator_func returned: %d", result_code)); + result_code= compl_result_code= 0; + if (operator_func != &handler::ha_analyze || + thd->variables.optimizer_use_stat_tables < 3) + { + DBUG_PRINT("admin", ("calling operator_func '%s'", operator_name)); + result_code = (table->table->file->*operator_func)(thd, check_opt); + DBUG_PRINT("admin", ("operator_func returned: %d", result_code)); + } + + if (operator_func == &handler::ha_analyze && + thd->variables.optimizer_use_stat_tables > 0) + { + if (!(compl_result_code= + collect_statistics_for_table(thd, table->table))) + compl_result_code= update_statistics_for_table(thd, table->table); + } if (result_code == HA_ADMIN_NOT_IMPLEMENTED && need_repair_or_alter) { @@ -4958,6 +4972,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, */ result_code= admin_recreate_table(thd, table); } + send_result: lex->cleanup_after_one_table_open(); diff --git a/sql/structs.h b/sql/structs.h index c2bdf6db747..77c94058b40 100644 --- a/sql/structs.h +++ b/sql/structs.h @@ -102,6 +102,31 @@ typedef struct st_key { For temporary heap tables this member is NULL. */ ulong *rec_per_key; + + /* Statistical data on an index prefixes */ + class Index_statistics + { + public: + /* + The k-th element of this array contains the ratio N/D, + where N is the number of index entries without nulls + in the first k components, and D is the number of distinct + k-component prefixes among them + */ + double *avg_frequency; + }; + + /* + This structure is used for statistical data on the index + that has been read from the statistical table index_stat + */ + Index_statistics read_stat; + /* + This structure is used for statistical data on the index that + is collected by the function collect_statistics_for_table + */ + Index_statistics write_stat; + union { int bdb_return_if_eq; } handler; diff --git a/sql/table.cc b/sql/table.cc index 7b417b95319..f4923a1e841 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -489,6 +489,12 @@ inline bool is_system_table_name(const char *name, uint length) my_tolower(ci, name[2]) == 'm' && my_tolower(ci, name[3]) == 'e') || + /* one of mysql.*_stat tables */ + (my_tolower(ci, name[length-4]) == 's' && + my_tolower(ci, name[length-3]) == 't' && + my_tolower(ci, name[length-2]) == 'a' && + my_tolower(ci, name[length-1]) == 't') || + /* mysql.event table */ (my_tolower(ci, name[0]) == 'e' && my_tolower(ci, name[1]) == 'v' && @@ -698,6 +704,8 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, uchar *disk_buff, *strpos, *null_flags, *null_pos, *options; uchar *buff= 0; ulong pos, record_offset, *rec_per_key, rec_buff_length; + double *read_avg_frequency= 0; + double *write_avg_frequency= 0; handler *handler_file= 0; KEY *keyinfo; KEY_PART_INFO *key_part; @@ -812,7 +820,13 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, if (!(rec_per_key= (ulong*) alloc_root(&share->mem_root, sizeof(ulong)*key_parts))) goto err; - + if (!(read_avg_frequency= (double*) alloc_root(&share->mem_root, + sizeof(double)*key_parts))) + goto err; + if (!(write_avg_frequency= (double*) alloc_root(&share->mem_root, + sizeof(double)*key_parts))) + goto err; + for (i=0 ; i < keys ; i++, keyinfo++) { if (new_frm_ver >= 3) @@ -835,9 +849,13 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, keyinfo->key_part= key_part; keyinfo->rec_per_key= rec_per_key; + keyinfo->read_stat.avg_frequency= read_avg_frequency; + keyinfo->write_stat.avg_frequency= write_avg_frequency; for (j=keyinfo->key_parts ; j-- ; key_part++) { *rec_per_key++=0; + *read_avg_frequency++= 0; + *write_avg_frequency++= 0; key_part->fieldnr= (uint16) (uint2korr(strpos) & FIELD_NR_MASK); key_part->offset= (uint) uint2korr(strpos+2)-1; key_part->key_type= (uint) uint2korr(strpos+5); diff --git a/sql/table.h b/sql/table.h index 376aa9824dc..bdfcaf9b5db 100644 --- a/sql/table.h +++ b/sql/table.h @@ -747,6 +747,25 @@ struct st_table { */ query_id_t query_id; + /* Statistical data on a table */ + class Table_statistics + { + public: + my_bool cardinality_is_null; /* TRUE if the cardinality is unknown */ + ha_rows cardinality; /* Number of rows in the table */ + }; + + /* + This structure is used for statistical data on the table + that has been read from the statistical table table_stat + */ + Table_statistics read_stat; + /* + This structure is used for statistical data on the table that + is collected by the function collect_statistics_for_table + */ + Table_statistics write_stat; + /* For each key that has quick_keys.is_set(key) == TRUE: estimate of #records and max #key parts that range access would use. From 7895f510a4019a8b96e447ca95b4e1ee4a9b6272 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 4 Jan 2012 18:32:21 -0800 Subject: [PATCH 02/35] In statistics.test: Saved at the very beginning and restored at the very end the value of optimizer_use_stat_tables. --- mysql-test/r/statistics.result | 2 ++ mysql-test/t/statistics.test | 5 ++++- 2 files changed, 6 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 424dec3bb9d..59af26014c6 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -1,4 +1,5 @@ drop table if exists t1,t2; +set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; CREATE VIEW table_stat AS SELECT * FROM mysql.table_stat; CREATE VIEW column_stat AS @@ -453,3 +454,4 @@ DELETE FROM mysql.index_stat; DROP VIEW test.table_stat; DROP VIEW test.column_stat; DROP VIEW test.index_stat; +set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 9ea57aca14a..0a32fcde881 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -3,6 +3,8 @@ drop table if exists t1,t2; --enable_warnings +set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; + CREATE VIEW table_stat AS SELECT * FROM mysql.table_stat; @@ -286,5 +288,6 @@ DROP VIEW test.table_stat; DROP VIEW test.column_stat; DROP VIEW test.index_stat; - +set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; + \ No newline at end of file From 699dc423584fa86aafc9346377a02b98b1eebf47 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 5 Jan 2012 18:55:37 -0800 Subject: [PATCH 03/35] Fixed a compiler warning. Adjusted results for mysql_upgrade.test --- mysql-test/r/mysql_upgrade.result | 18 ++++++++++++++++++ sql/field.h | 2 +- 2 files changed, 19 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/mysql_upgrade.result b/mysql-test/r/mysql_upgrade.result index ca23dc9cca1..f0a7a036f0c 100644 --- a/mysql-test/r/mysql_upgrade.result +++ b/mysql-test/r/mysql_upgrade.result @@ -7,6 +7,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -16,11 +17,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -42,6 +45,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -51,11 +55,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -77,6 +83,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -86,11 +93,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -115,6 +124,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -124,11 +134,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -156,6 +168,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -165,11 +178,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK @@ -200,6 +215,7 @@ mtr mtr.global_suppressions OK mtr.test_suppressions OK mysql +mysql.column_stat OK mysql.columns_priv OK mysql.db OK mysql.event OK @@ -209,11 +225,13 @@ mysql.help_keyword OK mysql.help_relation OK mysql.help_topic OK mysql.host OK +mysql.index_stat OK mysql.ndb_binlog_index OK mysql.plugin OK mysql.proc OK mysql.procs_priv OK mysql.servers OK +mysql.table_stat OK mysql.tables_priv OK mysql.time_zone OK mysql.time_zone_leap_second OK diff --git a/sql/field.h b/sql/field.h index 04b7baac89a..9f5ab19cf6c 100644 --- a/sql/field.h +++ b/sql/field.h @@ -349,7 +349,7 @@ public: (len= pack_length()) >= 4 && len < 256)) { uchar *str, *end; - for (str= ptr, end= str+len; end > str && end[-1] == ' '; end--); + for (str= ptr, end= str+len; end > str && end[-1] == ' '; end--) {} len=(uint) (end-str); return len; } From 6f91e434f79287a6d31204e981813f7c62f608cc Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 5 Jan 2012 22:45:08 -0800 Subject: [PATCH 04/35] Adjusted results for the test suite funcs_1. --- .../suite/funcs_1/r/is_columns_mysql.result | 34 +++++++++ .../funcs_1/r/is_statistics_mysql.result | 9 +++ .../r/is_table_constraints_mysql.result | 3 + .../suite/funcs_1/r/is_tables_mysql.result | 69 +++++++++++++++++++ 4 files changed, 115 insertions(+) diff --git a/mysql-test/suite/funcs_1/r/is_columns_mysql.result b/mysql-test/suite/funcs_1/r/is_columns_mysql.result index 8d486bae3a3..27e44be7eae 100644 --- a/mysql-test/suite/funcs_1/r/is_columns_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_columns_mysql.result @@ -9,6 +9,14 @@ NULL mysql columns_priv Host 1 NO char 60 180 NULL NULL NULL utf8 utf8_bin char NULL mysql columns_priv Table_name 4 NO char 64 192 NULL NULL NULL utf8 utf8_bin char(64) PRI select,insert,update,references NULL mysql columns_priv Timestamp 6 CURRENT_TIMESTAMP NO timestamp NULL NULL NULL NULL 0 NULL NULL timestamp on update CURRENT_TIMESTAMP select,insert,update,references NULL mysql columns_priv User 3 NO char 16 48 NULL NULL NULL utf8 utf8_bin char(16) PRI select,insert,update,references +NULL mysql column_stat avg_frequency 8 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +NULL mysql column_stat avg_length 7 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +NULL mysql column_stat column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +NULL mysql column_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +NULL mysql column_stat max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references +NULL mysql column_stat min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references +NULL mysql column_stat nulls_ratio 6 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +NULL mysql column_stat table_name 2 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references NULL mysql db Alter_priv 13 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references NULL mysql db Alter_routine_priv 19 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references NULL mysql db Create_priv 8 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references @@ -97,6 +105,11 @@ NULL mysql host Select_priv 3 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci NULL mysql host Show_view_priv 16 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references NULL mysql host Trigger_priv 20 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references NULL mysql host Update_priv 5 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references +NULL mysql index_stat avg_frequency 5 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +NULL mysql index_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +NULL mysql index_stat index_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +NULL mysql index_stat prefix_arity 4 NULL NO int NULL NULL 10 0 NULL NULL NULL int(11) unsigned PRI select,insert,update,references +NULL mysql index_stat table_name 2 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references NULL mysql ndb_binlog_index deletes 6 NULL NO bigint NULL NULL 20 0 NULL NULL NULL bigint(20) unsigned select,insert,update,references NULL mysql ndb_binlog_index epoch 3 NULL NO bigint NULL NULL 20 0 NULL NULL NULL bigint(20) unsigned PRI select,insert,update,references NULL mysql ndb_binlog_index File 2 NULL NO varchar 255 255 NULL NULL NULL latin1 latin1_swedish_ci varchar(255) select,insert,update,references @@ -162,6 +175,9 @@ NULL mysql tables_priv Table_name 4 NO char 64 192 NULL NULL NULL utf8 utf8_bin NULL mysql tables_priv Table_priv 7 NO set 98 294 NULL NULL NULL utf8 utf8_general_ci set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') select,insert,update,references NULL mysql tables_priv Timestamp 6 CURRENT_TIMESTAMP NO timestamp NULL NULL NULL NULL 0 NULL NULL timestamp on update CURRENT_TIMESTAMP select,insert,update,references NULL mysql tables_priv User 3 NO char 16 48 NULL NULL NULL utf8 utf8_bin char(16) PRI select,insert,update,references +NULL mysql table_stat cardinality 3 NULL YES bigint NULL NULL 20 0 NULL NULL NULL bigint(21) unsigned select,insert,update,references +NULL mysql table_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +NULL mysql table_stat table_name 2 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references NULL mysql time_zone Time_zone_id 1 NULL NO int NULL NULL 10 0 NULL NULL NULL int(10) unsigned PRI auto_increment select,insert,update,references NULL mysql time_zone Use_leap_seconds 2 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('Y','N') select,insert,update,references NULL mysql time_zone_leap_second Correction 2 NULL NO int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references @@ -250,6 +266,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME 3.0000 char utf8 utf8_bin 3.0000 enum utf8 utf8_bin +3.0000 varchar utf8 utf8_bin 3.0000 char utf8 utf8_general_ci 3.0000 enum utf8 utf8_general_ci 3.0000 set utf8 utf8_general_ci @@ -266,6 +283,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME NULL bigint NULL NULL NULL datetime NULL NULL +NULL double NULL NULL NULL int NULL NULL NULL smallint NULL NULL NULL time NULL NULL @@ -294,6 +312,14 @@ COL_CML TABLE_SCHEMA TABLE_NAME COLUMN_NAME DATA_TYPE CHARACTER_MAXIMUM_LENGTH C 3.0000 mysql columns_priv Column_name char 64 192 utf8 utf8_bin char(64) NULL mysql columns_priv Timestamp timestamp NULL NULL NULL NULL timestamp 3.0000 mysql columns_priv Column_priv set 31 93 utf8 utf8_general_ci set('Select','Insert','Update','References') +3.0000 mysql column_stat db_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql column_stat table_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql column_stat column_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql column_stat min_value varchar 255 765 utf8 utf8_bin varchar(255) +3.0000 mysql column_stat max_value varchar 255 765 utf8 utf8_bin varchar(255) +NULL mysql column_stat nulls_ratio double NULL NULL NULL NULL double +NULL mysql column_stat avg_length double NULL NULL NULL NULL double +NULL mysql column_stat avg_frequency double NULL NULL NULL NULL double 3.0000 mysql db Host char 60 180 utf8 utf8_bin char(60) 3.0000 mysql db Db char 64 192 utf8 utf8_bin char(64) 3.0000 mysql db User char 16 48 utf8 utf8_bin char(16) @@ -382,6 +408,11 @@ NULL mysql help_topic help_category_id smallint NULL NULL NULL NULL smallint(5) 3.0000 mysql host Alter_routine_priv enum 1 3 utf8 utf8_general_ci enum('N','Y') 3.0000 mysql host Execute_priv enum 1 3 utf8 utf8_general_ci enum('N','Y') 3.0000 mysql host Trigger_priv enum 1 3 utf8 utf8_general_ci enum('N','Y') +3.0000 mysql index_stat db_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql index_stat table_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql index_stat index_name varchar 64 192 utf8 utf8_bin varchar(64) +NULL mysql index_stat prefix_arity int NULL NULL NULL NULL int(11) unsigned +NULL mysql index_stat avg_frequency double NULL NULL NULL NULL double NULL mysql ndb_binlog_index Position bigint NULL NULL NULL NULL bigint(20) unsigned 1.0000 mysql ndb_binlog_index File varchar 255 255 latin1 latin1_swedish_ci varchar(255) NULL mysql ndb_binlog_index epoch bigint NULL NULL NULL NULL bigint(20) unsigned @@ -447,6 +478,9 @@ NULL mysql slow_log server_id int NULL NULL NULL NULL int(10) unsigned NULL mysql tables_priv Timestamp timestamp NULL NULL NULL NULL timestamp 3.0000 mysql tables_priv Table_priv set 98 294 utf8 utf8_general_ci set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') 3.0000 mysql tables_priv Column_priv set 31 93 utf8 utf8_general_ci set('Select','Insert','Update','References') +3.0000 mysql table_stat db_name varchar 64 192 utf8 utf8_bin varchar(64) +3.0000 mysql table_stat table_name varchar 64 192 utf8 utf8_bin varchar(64) +NULL mysql table_stat cardinality bigint NULL NULL NULL NULL bigint(21) unsigned NULL mysql time_zone Time_zone_id int NULL NULL NULL NULL int(10) unsigned 3.0000 mysql time_zone Use_leap_seconds enum 1 3 utf8 utf8_general_ci enum('Y','N') NULL mysql time_zone_leap_second Transition_time bigint NULL NULL NULL NULL bigint(20) diff --git a/mysql-test/suite/funcs_1/r/is_statistics_mysql.result b/mysql-test/suite/funcs_1/r/is_statistics_mysql.result index ee37f6ef222..56a852ff6a1 100644 --- a/mysql-test/suite/funcs_1/r/is_statistics_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_statistics_mysql.result @@ -12,6 +12,9 @@ NULL mysql columns_priv 0 mysql PRIMARY 2 Db A #CARD# NULL NULL BTREE NULL mysql columns_priv 0 mysql PRIMARY 3 User A #CARD# NULL NULL BTREE NULL mysql columns_priv 0 mysql PRIMARY 4 Table_name A #CARD# NULL NULL BTREE NULL mysql columns_priv 0 mysql PRIMARY 5 Column_name A #CARD# NULL NULL BTREE +NULL mysql column_stat 0 mysql PRIMARY 1 db_name A #CARD# NULL NULL BTREE +NULL mysql column_stat 0 mysql PRIMARY 2 table_name A #CARD# NULL NULL BTREE +NULL mysql column_stat 0 mysql PRIMARY 3 column_name A #CARD# NULL NULL BTREE NULL mysql db 0 mysql PRIMARY 1 Host A #CARD# NULL NULL BTREE NULL mysql db 0 mysql PRIMARY 2 Db A #CARD# NULL NULL BTREE NULL mysql db 0 mysql PRIMARY 3 User A #CARD# NULL NULL BTREE @@ -29,6 +32,10 @@ NULL mysql help_topic 0 mysql name 1 name A #CARD# NULL NULL BTREE NULL mysql help_topic 0 mysql PRIMARY 1 help_topic_id A #CARD# NULL NULL BTREE NULL mysql host 0 mysql PRIMARY 1 Host A #CARD# NULL NULL BTREE NULL mysql host 0 mysql PRIMARY 2 Db A #CARD# NULL NULL BTREE +NULL mysql index_stat 0 mysql PRIMARY 1 db_name A #CARD# NULL NULL BTREE +NULL mysql index_stat 0 mysql PRIMARY 2 table_name A #CARD# NULL NULL BTREE +NULL mysql index_stat 0 mysql PRIMARY 3 index_name A #CARD# NULL NULL BTREE +NULL mysql index_stat 0 mysql PRIMARY 4 prefix_arity A #CARD# NULL NULL BTREE NULL mysql ndb_binlog_index 0 mysql PRIMARY 1 epoch A #CARD# NULL NULL BTREE NULL mysql plugin 0 mysql PRIMARY 1 name A #CARD# NULL NULL BTREE NULL mysql proc 0 mysql PRIMARY 1 db A #CARD# NULL NULL BTREE @@ -46,6 +53,8 @@ NULL mysql tables_priv 0 mysql PRIMARY 1 Host A #CARD# NULL NULL BTREE NULL mysql tables_priv 0 mysql PRIMARY 2 Db A #CARD# NULL NULL BTREE NULL mysql tables_priv 0 mysql PRIMARY 3 User A #CARD# NULL NULL BTREE NULL mysql tables_priv 0 mysql PRIMARY 4 Table_name A #CARD# NULL NULL BTREE +NULL mysql table_stat 0 mysql PRIMARY 1 db_name A #CARD# NULL NULL BTREE +NULL mysql table_stat 0 mysql PRIMARY 2 table_name A #CARD# NULL NULL BTREE NULL mysql time_zone 0 mysql PRIMARY 1 Time_zone_id A #CARD# NULL NULL BTREE NULL mysql time_zone_leap_second 0 mysql PRIMARY 1 Transition_time A #CARD# NULL NULL BTREE NULL mysql time_zone_name 0 mysql PRIMARY 1 Name A #CARD# NULL NULL BTREE diff --git a/mysql-test/suite/funcs_1/r/is_table_constraints_mysql.result b/mysql-test/suite/funcs_1/r/is_table_constraints_mysql.result index ba5da23f069..25c6fbafdb0 100644 --- a/mysql-test/suite/funcs_1/r/is_table_constraints_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_table_constraints_mysql.result @@ -8,6 +8,7 @@ WHERE table_schema = 'mysql' ORDER BY table_schema,table_name,constraint_name; CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_SCHEMA TABLE_NAME CONSTRAINT_TYPE NULL mysql PRIMARY mysql columns_priv PRIMARY KEY +NULL mysql PRIMARY mysql column_stat PRIMARY KEY NULL mysql PRIMARY mysql db PRIMARY KEY NULL mysql PRIMARY mysql event PRIMARY KEY NULL mysql PRIMARY mysql func PRIMARY KEY @@ -19,12 +20,14 @@ NULL mysql PRIMARY mysql help_relation PRIMARY KEY NULL mysql name mysql help_topic UNIQUE NULL mysql PRIMARY mysql help_topic PRIMARY KEY NULL mysql PRIMARY mysql host PRIMARY KEY +NULL mysql PRIMARY mysql index_stat PRIMARY KEY NULL mysql PRIMARY mysql ndb_binlog_index PRIMARY KEY NULL mysql PRIMARY mysql plugin PRIMARY KEY NULL mysql PRIMARY mysql proc PRIMARY KEY NULL mysql PRIMARY mysql procs_priv PRIMARY KEY NULL mysql PRIMARY mysql servers PRIMARY KEY NULL mysql PRIMARY mysql tables_priv PRIMARY KEY +NULL mysql PRIMARY mysql table_stat PRIMARY KEY NULL mysql PRIMARY mysql time_zone PRIMARY KEY NULL mysql PRIMARY mysql time_zone_leap_second PRIMARY KEY NULL mysql PRIMARY mysql time_zone_name PRIMARY KEY diff --git a/mysql-test/suite/funcs_1/r/is_tables_mysql.result b/mysql-test/suite/funcs_1/r/is_tables_mysql.result index b41318d9bae..21c58ac118c 100644 --- a/mysql-test/suite/funcs_1/r/is_tables_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_tables_mysql.result @@ -37,6 +37,29 @@ user_comment Column privileges Separator ----------------------------------------------------- TABLE_CATALOG NULL TABLE_SCHEMA mysql +TABLE_NAME column_stat +TABLE_TYPE BASE TABLE +ENGINE MYISAM_OR_MARIA +VERSION 10 +ROW_FORMAT DYNAMIC_OR_PAGE +TABLE_ROWS #TBLR# +AVG_ROW_LENGTH #ARL# +DATA_LENGTH #DL# +MAX_DATA_LENGTH #MDL# +INDEX_LENGTH #IL# +DATA_FREE #DF# +AUTO_INCREMENT NULL +CREATE_TIME #CRT# +UPDATE_TIME #UT# +CHECK_TIME #CT# +TABLE_COLLATION utf8_bin +CHECKSUM NULL +CREATE_OPTIONS #CO# +TABLE_COMMENT #TC# +user_comment Statistics on Columns +Separator ----------------------------------------------------- +TABLE_CATALOG NULL +TABLE_SCHEMA mysql TABLE_NAME db TABLE_TYPE BASE TABLE ENGINE MYISAM_OR_MARIA @@ -244,6 +267,29 @@ user_comment Host privileges; Merged with database privileges Separator ----------------------------------------------------- TABLE_CATALOG NULL TABLE_SCHEMA mysql +TABLE_NAME index_stat +TABLE_TYPE BASE TABLE +ENGINE MYISAM_OR_MARIA +VERSION 10 +ROW_FORMAT DYNAMIC_OR_PAGE +TABLE_ROWS #TBLR# +AVG_ROW_LENGTH #ARL# +DATA_LENGTH #DL# +MAX_DATA_LENGTH #MDL# +INDEX_LENGTH #IL# +DATA_FREE #DF# +AUTO_INCREMENT NULL +CREATE_TIME #CRT# +UPDATE_TIME #UT# +CHECK_TIME #CT# +TABLE_COLLATION utf8_bin +CHECKSUM NULL +CREATE_OPTIONS #CO# +TABLE_COMMENT #TC# +user_comment Statistics on Indexes +Separator ----------------------------------------------------- +TABLE_CATALOG NULL +TABLE_SCHEMA mysql TABLE_NAME ndb_binlog_index TABLE_TYPE BASE TABLE ENGINE MYISAM_OR_MARIA @@ -405,6 +451,29 @@ user_comment Table privileges Separator ----------------------------------------------------- TABLE_CATALOG NULL TABLE_SCHEMA mysql +TABLE_NAME table_stat +TABLE_TYPE BASE TABLE +ENGINE MYISAM_OR_MARIA +VERSION 10 +ROW_FORMAT DYNAMIC_OR_PAGE +TABLE_ROWS #TBLR# +AVG_ROW_LENGTH #ARL# +DATA_LENGTH #DL# +MAX_DATA_LENGTH #MDL# +INDEX_LENGTH #IL# +DATA_FREE #DF# +AUTO_INCREMENT NULL +CREATE_TIME #CRT# +UPDATE_TIME #UT# +CHECK_TIME #CT# +TABLE_COLLATION utf8_bin +CHECKSUM NULL +CREATE_OPTIONS #CO# +TABLE_COMMENT #TC# +user_comment Statistics on Tables +Separator ----------------------------------------------------- +TABLE_CATALOG NULL +TABLE_SCHEMA mysql TABLE_NAME time_zone TABLE_TYPE BASE TABLE ENGINE MYISAM_OR_MARIA From d0dc6e07f6b33447465db149d84cff86020afc34 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 7 Jan 2012 00:34:30 -0800 Subject: [PATCH 05/35] Made statistics.test platform independent. --- mysql-test/r/statistics.result | 172 +++++++++++++++++---------------- mysql-test/t/statistics.test | 22 +++-- 2 files changed, 107 insertions(+), 87 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 59af26014c6..3a83f9ba66c 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -330,35 +330,40 @@ INDEX (Percentage) ) CHARACTER SET utf8 COLLATE utf8_bin; set optimizer_use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; -SELECT * FROM test.table_stat; -db_name table_name cardinality -world Country 239 -world City 4079 -world CountryLanguage 984 -SELECT * FROM test.column_stat; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -world Country Code ABW ZWE 0.0000 3.0000 1.0000 -world Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 -world Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 -world Country Population 0 1277558000 0.0000 4.0000 1.0575 -world Country Capital 1 4074 0.0293 4.0000 1.0000 -world City ID 1 4079 0.0000 4.0000 1.0000 -world City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 -world City Country ABW ZWE 0.0000 3.0000 17.5819 -world City Population 42 10500000 0.0000 4.0000 1.0467 -world CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 -world CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 -world CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 -SELECT * FROM test.index_stat; -db_name table_name index_name prefix_arity avg_frequency -world Country PRIMARY 1 1.0000 -world Country Name 1 1.0000 -world City PRIMARY 1 1.0000 -world City Population 1 1.0467 -world City Country 1 17.5819 -world CountryLanguage PRIMARY 1 4.2232 -world CountryLanguage PRIMARY 2 1.0000 -world CountryLanguage Percentage 1 2.7640 +SELECT UPPER(db_name), UPPER(table_name), cardinality +FROM test.table_stat; +UPPER(db_name) UPPER(table_name) cardinality +WORLD COUNTRY 239 +WORLD CITY 4079 +WORLD COUNTRYLANGUAGE 984 +SELECT UPPER(db_name), UPPER(table_name), +column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency +FROM test.column_stat; +UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency +WORLD COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 +WORLD COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +WORLD COUNTRY SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +WORLD COUNTRY Population 0 1277558000 0.0000 4.0000 1.0575 +WORLD COUNTRY Capital 1 4074 0.0293 4.0000 1.0000 +WORLD CITY ID 1 4079 0.0000 4.0000 1.0000 +WORLD CITY Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +WORLD CITY Country ABW ZWE 0.0000 3.0000 17.5819 +WORLD CITY Population 42 10500000 0.0000 4.0000 1.0467 +WORLD COUNTRYLANGUAGE Country ABW ZWE 0.0000 3.0000 4.2232 +WORLD COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +WORLD COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT UPPER(db_name), UPPER(table_name), +index_name, prefix_arity, avg_frequency +FROM test.index_stat; +UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency +WORLD COUNTRY PRIMARY 1 1.0000 +WORLD COUNTRY Name 1 1.0000 +WORLD CITY PRIMARY 1 1.0000 +WORLD CITY Population 1 1.0467 +WORLD CITY Country 1 17.5819 +WORLD COUNTRYLANGUAGE PRIMARY 1 4.2232 +WORLD COUNTRYLANGUAGE PRIMARY 2 1.0000 +WORLD COUNTRYLANGUAGE Percentage 1 2.7640 use test; set optimizer_use_stat_tables='never'; CREATE DATABASE world_innodb; @@ -393,58 +398,63 @@ ALTER TABLE City ENGINE=InnoDB; ALTER TABLE CountryLanguage ENGINE=InnoDB; set optimizer_use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; -SELECT * FROM test.table_stat; -db_name table_name cardinality -world Country 239 -world City 4079 -world CountryLanguage 984 -world_innodb Country 239 -world_innodb City 4079 -world_innodb CountryLanguage 984 -SELECT * FROM test.column_stat; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -world Country Code ABW ZWE 0.0000 3.0000 1.0000 -world Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 -world Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 -world Country Population 0 1277558000 0.0000 4.0000 1.0575 -world Country Capital 1 4074 0.0293 4.0000 1.0000 -world City ID 1 4079 0.0000 4.0000 1.0000 -world City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 -world City Country ABW ZWE 0.0000 3.0000 17.5819 -world City Population 42 10500000 0.0000 4.0000 1.0467 -world CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 -world CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 -world CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 -world_innodb Country Code ABW ZWE 0.0000 3.0000 1.0000 -world_innodb Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 -world_innodb Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 -world_innodb Country Population 0 1277558000 0.0000 4.0000 1.0575 -world_innodb Country Capital 1 4074 0.0293 4.0000 1.0000 -world_innodb City ID 1 4079 0.0000 4.0000 1.0000 -world_innodb City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 -world_innodb City Country ABW ZWE 0.0000 3.0000 17.5819 -world_innodb City Population 42 10500000 0.0000 4.0000 1.0467 -world_innodb CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 -world_innodb CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 -world_innodb CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 -SELECT * FROM test.index_stat; -db_name table_name index_name prefix_arity avg_frequency -world Country PRIMARY 1 1.0000 -world Country Name 1 1.0000 -world City PRIMARY 1 1.0000 -world City Population 1 1.0467 -world City Country 1 17.5819 -world CountryLanguage PRIMARY 1 4.2232 -world CountryLanguage PRIMARY 2 1.0000 -world CountryLanguage Percentage 1 2.7640 -world_innodb Country PRIMARY 1 1.0000 -world_innodb Country Name 1 1.0000 -world_innodb City PRIMARY 1 1.0000 -world_innodb City Population 1 1.0467 -world_innodb City Country 1 17.5819 -world_innodb CountryLanguage PRIMARY 1 4.2232 -world_innodb CountryLanguage PRIMARY 2 1.0000 -world_innodb CountryLanguage Percentage 1 2.7640 +SELECT UPPER(db_name), UPPER(table_name), cardinality +FROM test.table_stat; +UPPER(db_name) UPPER(table_name) cardinality +WORLD COUNTRY 239 +WORLD CITY 4079 +WORLD COUNTRYLANGUAGE 984 +WORLD_INNODB COUNTRY 239 +WORLD_INNODB CITY 4079 +WORLD_INNODB COUNTRYLANGUAGE 984 +SELECT UPPER(db_name), UPPER(table_name), +column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency +FROM test.column_stat; +UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency +WORLD COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 +WORLD COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +WORLD COUNTRY SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +WORLD COUNTRY Population 0 1277558000 0.0000 4.0000 1.0575 +WORLD COUNTRY Capital 1 4074 0.0293 4.0000 1.0000 +WORLD CITY ID 1 4079 0.0000 4.0000 1.0000 +WORLD CITY Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +WORLD CITY Country ABW ZWE 0.0000 3.0000 17.5819 +WORLD CITY Population 42 10500000 0.0000 4.0000 1.0467 +WORLD COUNTRYLANGUAGE Country ABW ZWE 0.0000 3.0000 4.2232 +WORLD COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +WORLD COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 +WORLD_INNODB COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 +WORLD_INNODB COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +WORLD_INNODB COUNTRY SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +WORLD_INNODB COUNTRY Population 0 1277558000 0.0000 4.0000 1.0575 +WORLD_INNODB COUNTRY Capital 1 4074 0.0293 4.0000 1.0000 +WORLD_INNODB CITY ID 1 4079 0.0000 4.0000 1.0000 +WORLD_INNODB CITY Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +WORLD_INNODB CITY Country ABW ZWE 0.0000 3.0000 17.5819 +WORLD_INNODB CITY Population 42 10500000 0.0000 4.0000 1.0467 +WORLD_INNODB COUNTRYLANGUAGE Country ABW ZWE 0.0000 3.0000 4.2232 +WORLD_INNODB COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +WORLD_INNODB COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT UPPER(db_name), UPPER(table_name), +index_name, prefix_arity, avg_frequency +FROM test.index_stat; +UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency +WORLD COUNTRY PRIMARY 1 1.0000 +WORLD COUNTRY Name 1 1.0000 +WORLD CITY PRIMARY 1 1.0000 +WORLD CITY Population 1 1.0467 +WORLD CITY Country 1 17.5819 +WORLD COUNTRYLANGUAGE PRIMARY 1 4.2232 +WORLD COUNTRYLANGUAGE PRIMARY 2 1.0000 +WORLD COUNTRYLANGUAGE Percentage 1 2.7640 +WORLD_INNODB COUNTRY PRIMARY 1 1.0000 +WORLD_INNODB COUNTRY Name 1 1.0000 +WORLD_INNODB CITY PRIMARY 1 1.0000 +WORLD_INNODB CITY Population 1 1.0467 +WORLD_INNODB CITY Country 1 17.5819 +WORLD_INNODB COUNTRYLANGUAGE PRIMARY 1 4.2232 +WORLD_INNODB COUNTRYLANGUAGE PRIMARY 2 1.0000 +WORLD_INNODB COUNTRYLANGUAGE Percentage 1 2.7640 use test; DROP DATABASE world; DROP DATABASE world_innodb; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 0a32fcde881..81108c9846d 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -239,9 +239,14 @@ set optimizer_use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; --enable_result_log -SELECT * FROM test.table_stat; -SELECT * FROM test.column_stat; -SELECT * FROM test.index_stat; +SELECT UPPER(db_name), UPPER(table_name), cardinality + FROM test.table_stat; +SELECT UPPER(db_name), UPPER(table_name), + column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency + FROM test.column_stat; +SELECT UPPER(db_name), UPPER(table_name), + index_name, prefix_arity, avg_frequency + FROM test.index_stat; use test; @@ -271,9 +276,14 @@ set optimizer_use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; --enable_result_log -SELECT * FROM test.table_stat; -SELECT * FROM test.column_stat; -SELECT * FROM test.index_stat; +SELECT UPPER(db_name), UPPER(table_name), cardinality + FROM test.table_stat; +SELECT UPPER(db_name), UPPER(table_name), + column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency + FROM test.column_stat; +SELECT UPPER(db_name), UPPER(table_name), + index_name, prefix_arity, avg_frequency + FROM test.index_stat; use test; From 6c1aab92d25580643595962ae61a963a3e2fbd9d Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 9 Jan 2012 21:14:34 -0800 Subject: [PATCH 06/35] MWL#248: added the option skip-stat-tables. --- sql/mysql_priv.h | 1 + sql/mysqld.cc | 10 +++++++++- sql/sql_base.cc | 2 +- sql/sql_table.cc | 2 +- 4 files changed, 12 insertions(+), 3 deletions(-) diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index d9d61a84684..9b1f4423eee 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -2237,6 +2237,7 @@ extern char* opt_secure_file_priv; extern my_bool opt_log_slow_admin_statements, opt_log_slow_slave_statements; extern my_bool opt_query_cache_strip_comments; extern my_bool sp_automatic_privileges, opt_noacl; +extern my_bool opt_no_stat_tables; extern my_bool opt_old_style_user_limits, trust_function_creators; extern uint opt_crash_binlog_innodb; extern char *shared_memory_base_name, *mysqld_unix_port; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 4868ded7d00..66b145a9300 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -626,6 +626,7 @@ my_bool opt_old_style_user_limits= 0, trust_function_creators= 0; */ volatile bool mqh_used = 0; my_bool opt_noacl; +my_bool opt_no_stat_tables; my_bool sp_automatic_privileges= 1; ulong opt_binlog_rows_event_max_size; @@ -6191,7 +6192,8 @@ enum options_mysqld OPT_MAX_LONG_DATA_SIZE, OPT_MASTER_VERIFY_CHECKSUM, OPT_SLAVE_SQL_VERIFY_CHECKSUM, - OPT_QUERY_CACHE_STRIP_COMMENTS + OPT_QUERY_CACHE_STRIP_COMMENTS, + OPT_SKIP_STAT_TABLES }; @@ -7018,6 +7020,11 @@ each time the SQL thread starts.", &opt_noacl, &opt_noacl, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0}, #endif + {"skip-stat-tables", OPT_SKIP_STAT_TABLES, + "Start without statistical tables. Statistical data on table cardinalities, " + "columns and indexes from these tables become unavailable", + &opt_no_stat_tables, &opt_no_stat_tables, 0, GET_BOOL, NO_ARG, + 0, 0, 0, 0, 0, 0}, {"skip-host-cache", OPT_SKIP_HOST_CACHE, "Don't cache host names.", 0, 0, 0, GET_NO_ARG, NO_ARG, 0, 0, 0, 0, 0, 0}, {"skip-locking", OPT_SKIP_LOCK, @@ -9220,6 +9227,7 @@ mysqld_get_one_option(int optid, break; case OPT_BOOTSTRAP: opt_noacl=opt_bootstrap=1; + opt_no_stat_tables= 1; break; case OPT_LOG_SLOW_FILTER: global_system_variables.log_slow_filter= diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 5a4e2f53fe9..632639d60de 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4855,7 +4855,7 @@ int open_tables(THD *thd, TABLE_LIST **start, uint *counter, uint flags) parent_l->next_global= *parent_l->table->child_last_l; } - if (thd->variables.optimizer_use_stat_tables > 0) + if (!opt_no_stat_tables && thd->variables.optimizer_use_stat_tables > 0) { if (tables->table && tables->table->s && tables->table->s->table_category != TABLE_CATEGORY_SYSTEM) diff --git a/sql/sql_table.cc b/sql/sql_table.cc index c057834bdcc..cdf215a3bc7 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -4956,7 +4956,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, DBUG_PRINT("admin", ("operator_func returned: %d", result_code)); } - if (operator_func == &handler::ha_analyze && + if (operator_func == &handler::ha_analyze && !opt_no_stat_tables && thd->variables.optimizer_use_stat_tables > 0) { if (!(compl_result_code= From 1c0a89afcc1581187e8ee84abbd445da2bfa45d9 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 11 Apr 2012 17:14:06 -0700 Subject: [PATCH 07/35] The pilot implementation of mwl#250: Use the statistics from persistent statistical tables instead of the statistics provided by engine. --- mysql-test/r/stat_tables.result | 229 ++++++++++++++++++++++++ mysql-test/r/stat_tables_innodb.result | 231 +++++++++++++++++++++++++ mysql-test/t/stat_tables.test | 108 ++++++++++++ mysql-test/t/stat_tables_innodb.test | 7 + sql/multi_range_read.cc | 2 +- sql/mysqld.cc | 5 - sql/opt_range.cc | 35 ++-- sql/sql_base.h | 1 + sql/sql_delete.cc | 1 + sql/sql_join_cache.cc | 2 +- sql/sql_select.cc | 54 +++--- sql/sql_statistics.cc | 55 +++++- sql/structs.h | 14 ++ sql/table.cc | 10 +- sql/table.h | 4 + 15 files changed, 706 insertions(+), 52 deletions(-) create mode 100644 mysql-test/r/stat_tables.result create mode 100644 mysql-test/r/stat_tables_innodb.result create mode 100644 mysql-test/t/stat_tables.test create mode 100644 mysql-test/t/stat_tables_innodb.test diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result new file mode 100644 index 00000000000..089c7871506 --- /dev/null +++ b/mysql-test/r/stat_tables.result @@ -0,0 +1,229 @@ +set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; +set optimizer_use_stat_tables='preferably'; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1 +dbt3_s001 customer i_c_nationkey 1 6 +dbt3_s001 lineitem PRIMARY 1 4.003333333333333 +dbt3_s001 lineitem PRIMARY 2 1 +dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 +dbt3_s001 lineitem i_l_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey 1 600.5 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 +dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 +dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 +dbt3_s001 nation PRIMARY 1 1 +dbt3_s001 nation i_n_regionkey 1 5 +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 part PRIMARY 1 1 +dbt3_s001 part i_p_retailprice 1 1 +dbt3_s001 partsupp PRIMARY 1 3.5 +dbt3_s001 partsupp PRIMARY 2 1 +dbt3_s001 partsupp i_ps_partkey 1 3.5 +dbt3_s001 partsupp i_ps_suppkey 1 70 +dbt3_s001 region PRIMARY 1 1 +dbt3_s001 supplier PRIMARY 1 1 +dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_custkey i_o_orderdate 4 NULL 179 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE nation eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +1 SIMPLE supplier eq_ref PRIMARY,i_s_nationkey PRIMARY 4 dbt3_s001.lineitem.l_suppkey 1 Using where +select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +n_name revenue +PERU 321915.8715 +ARGENTINA 69817.1451 +set optimizer_switch=@save_optimizer_switch; +EXPLAIN select o_year, +sum(case when nation = 'UNITED STATES' then volume else 0 end) / +sum(volume) as mkt_share +from (select extract(year from o_orderdate) as o_year, +l_extendedprice * (1-l_discount) as volume, +n2.n_name as nation +from part, supplier, lineitem, orders, customer, +nation n1, nation n2, region +where p_partkey = l_partkey and s_suppkey = l_suppkey +and l_orderkey = o_orderkey and o_custkey = c_custkey +and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey +and r_name = 'AMERICA' and s_nationkey = n2.n_nationkey +and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'STANDARD BRUSHED STEEL' ) as all_nations +group by o_year +order by o_year; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ALL PRIMARY,i_o_orderdate,i_o_custkey NULL NULL NULL 1500 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE n1 eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +1 SIMPLE part eq_ref PRIMARY PRIMARY 4 dbt3_s001.lineitem.l_partkey 1 Using where +1 SIMPLE supplier eq_ref PRIMARY,i_s_nationkey PRIMARY 4 dbt3_s001.lineitem.l_suppkey 1 Using where +1 SIMPLE n2 eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 +select o_year, +sum(case when nation = 'UNITED STATES' then volume else 0 end) / +sum(volume) as mkt_share +from (select extract(year from o_orderdate) as o_year, +l_extendedprice * (1-l_discount) as volume, +n2.n_name as nation +from part, supplier, lineitem, orders, customer, +nation n1, nation n2, region +where p_partkey = l_partkey and s_suppkey = l_suppkey +and l_orderkey = o_orderkey and o_custkey = c_custkey +and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey +and r_name = 'AMERICA' and s_nationkey = n2.n_nationkey +and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'STANDARD BRUSHED STEEL' ) as all_nations +group by o_year +order by o_year; +o_year mkt_share +1995 0.4495521838895718 +1996 0.024585468215352495 +EXPLAIN select nation, o_year, sum(amount) as sum_profit +from (select n_name as nation, +extract(year from o_orderdate) as o_year, +l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount +from part, supplier, lineitem, partsupp, orders, nation +where s_suppkey = l_suppkey and ps_suppkey = l_suppkey +and ps_partkey = l_partkey and p_partkey = l_partkey +and o_orderkey = l_orderkey and s_nationkey = n_nationkey +and p_name like '%green%') as profit +group by nation, o_year +order by nation, o_year desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE supplier ALL PRIMARY,i_s_nationkey NULL NULL NULL 10 Using where; Using temporary; Using filesort +1 SIMPLE nation eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 +1 SIMPLE partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_suppkey 4 dbt3_s001.supplier.s_suppkey 70 +1 SIMPLE part eq_ref PRIMARY PRIMARY 4 dbt3_s001.partsupp.ps_partkey 1 Using where +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.supplier.s_suppkey 8 +1 SIMPLE orders eq_ref PRIMARY PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 +select nation, o_year, sum(amount) as sum_profit +from (select n_name as nation, +extract(year from o_orderdate) as o_year, +l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount +from part, supplier, lineitem, partsupp, orders, nation +where s_suppkey = l_suppkey and ps_suppkey = l_suppkey +and ps_partkey = l_partkey and p_partkey = l_partkey +and o_orderkey = l_orderkey and s_nationkey = n_nationkey +and p_name like '%green%') as profit +group by nation, o_year +order by nation, o_year desc; +nation o_year sum_profit +ARGENTINA 1997 18247.873399999993 +ARGENTINA 1996 7731.089399999995 +ARGENTINA 1995 134490.5697 +ARGENTINA 1994 36767.101500000004 +ARGENTINA 1993 35857.08 +ARGENTINA 1992 35740 +ETHIOPIA 1998 2758.7801999999992 +ETHIOPIA 1997 19419.294599999997 +ETHIOPIA 1995 51231.87439999999 +ETHIOPIA 1994 3578.9478999999974 +ETHIOPIA 1992 1525.8234999999986 +IRAN 1998 37817.229600000006 +IRAN 1997 52643.77359999999 +IRAN 1996 70143.7761 +IRAN 1995 84094.58260000001 +IRAN 1994 18140.925599999995 +IRAN 1993 78655.1676 +IRAN 1992 87142.23960000002 +IRAQ 1998 22860.8082 +IRAQ 1997 93676.24359999999 +IRAQ 1996 45103.3242 +IRAQ 1994 36010.728599999995 +IRAQ 1993 33221.9399 +IRAQ 1992 47755.05900000001 +KENYA 1998 44194.831999999995 +KENYA 1997 57578.36259999999 +KENYA 1996 59195.90210000001 +KENYA 1995 79262.6278 +KENYA 1994 102360.66609999999 +KENYA 1993 128422.0196 +KENYA 1992 181517.2089 +MOROCCO 1998 41797.823199999984 +MOROCCO 1997 23685.801799999994 +MOROCCO 1996 62115.19579999998 +MOROCCO 1995 42442.64300000001 +MOROCCO 1994 48655.878000000004 +MOROCCO 1993 22926.744400000003 +MOROCCO 1992 32239.8088 +PERU 1998 86999.36459999997 +PERU 1997 121110.41070000001 +PERU 1996 177040.40759999995 +PERU 1995 122247.94520000002 +PERU 1994 88046.25329999998 +PERU 1993 49379.813799999996 +PERU 1992 80646.86050000001 +UNITED KINGDOM 1998 50577.25560000001 +UNITED KINGDOM 1997 114288.8605 +UNITED KINGDOM 1996 147684.46480000002 +UNITED KINGDOM 1995 225267.65759999998 +UNITED KINGDOM 1994 140595.5864 +UNITED KINGDOM 1993 322548.49210000003 +UNITED KINGDOM 1992 67747.88279999999 +UNITED STATES 1998 3957.0431999999996 +UNITED STATES 1997 94729.5704 +UNITED STATES 1996 79297.85670000002 +UNITED STATES 1995 62201.23360000001 +UNITED STATES 1994 43075.629899999985 +UNITED STATES 1993 27168.486199999996 +UNITED STATES 1992 34092.366 +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; +EXPLAIN select o_orderkey, p_partkey +from part, lineitem, orders +where p_retailprice > 1100 and o_orderdate='1997-01-01' +and o_orderkey=l_orderkey and p_partkey=l_partkey; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ref PRIMARY,i_o_orderdate i_o_orderdate 4 const 1 +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +1 SIMPLE part eq_ref PRIMARY,i_p_retailprice PRIMARY 4 dbt3_s001.lineitem.l_partkey 1 Using where +select o_orderkey, p_partkey +from part, lineitem, orders +where p_retailprice > 1100 and o_orderdate='1997-01-01' +and o_orderkey=l_orderkey and p_partkey=l_partkey; +o_orderkey p_partkey +5895 200 +set optimizer_switch=@save_optimizer_switch; +DROP DATABASE dbt3_s001; +use test; +set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result new file mode 100644 index 00000000000..005e4c4828e --- /dev/null +++ b/mysql-test/r/stat_tables_innodb.result @@ -0,0 +1,231 @@ +SET SESSION STORAGE_ENGINE='InnoDB'; +set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; +set optimizer_use_stat_tables='preferably'; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1 +dbt3_s001 customer i_c_nationkey 1 6 +dbt3_s001 lineitem PRIMARY 1 4.003333333333333 +dbt3_s001 lineitem PRIMARY 2 1 +dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 +dbt3_s001 lineitem i_l_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey 1 600.5 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 +dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 +dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 +dbt3_s001 nation PRIMARY 1 1 +dbt3_s001 nation i_n_regionkey 1 5 +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 part PRIMARY 1 1 +dbt3_s001 part i_p_retailprice 1 1 +dbt3_s001 partsupp PRIMARY 1 3.5 +dbt3_s001 partsupp PRIMARY 2 1 +dbt3_s001 partsupp i_ps_partkey 1 3.5 +dbt3_s001 partsupp i_ps_suppkey 1 70 +dbt3_s001 region PRIMARY 1 1 +dbt3_s001 supplier PRIMARY 1 1 +dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_custkey i_o_orderdate 4 NULL 211 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE nation eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.customer.c_nationkey 1 Using index +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +n_name revenue +PERU 321915.8715 +ARGENTINA 69817.1451 +set optimizer_switch=@save_optimizer_switch; +EXPLAIN select o_year, +sum(case when nation = 'UNITED STATES' then volume else 0 end) / +sum(volume) as mkt_share +from (select extract(year from o_orderdate) as o_year, +l_extendedprice * (1-l_discount) as volume, +n2.n_name as nation +from part, supplier, lineitem, orders, customer, +nation n1, nation n2, region +where p_partkey = l_partkey and s_suppkey = l_suppkey +and l_orderkey = o_orderkey and o_custkey = c_custkey +and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey +and r_name = 'AMERICA' and s_nationkey = n2.n_nationkey +and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'STANDARD BRUSHED STEEL' ) as all_nations +group by o_year +order by o_year; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ALL PRIMARY,i_o_orderdate,i_o_custkey NULL NULL NULL 1500 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE n1 eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +1 SIMPLE part eq_ref PRIMARY PRIMARY 4 dbt3_s001.lineitem.l_partkey 1 Using where +1 SIMPLE supplier eq_ref PRIMARY,i_s_nationkey PRIMARY 4 dbt3_s001.lineitem.l_suppkey 1 Using where +1 SIMPLE n2 eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 +select o_year, +sum(case when nation = 'UNITED STATES' then volume else 0 end) / +sum(volume) as mkt_share +from (select extract(year from o_orderdate) as o_year, +l_extendedprice * (1-l_discount) as volume, +n2.n_name as nation +from part, supplier, lineitem, orders, customer, +nation n1, nation n2, region +where p_partkey = l_partkey and s_suppkey = l_suppkey +and l_orderkey = o_orderkey and o_custkey = c_custkey +and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey +and r_name = 'AMERICA' and s_nationkey = n2.n_nationkey +and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'STANDARD BRUSHED STEEL' ) as all_nations +group by o_year +order by o_year; +o_year mkt_share +1995 0.4495521838895718 +1996 0.024585468215352495 +EXPLAIN select nation, o_year, sum(amount) as sum_profit +from (select n_name as nation, +extract(year from o_orderdate) as o_year, +l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount +from part, supplier, lineitem, partsupp, orders, nation +where s_suppkey = l_suppkey and ps_suppkey = l_suppkey +and ps_partkey = l_partkey and p_partkey = l_partkey +and o_orderkey = l_orderkey and s_nationkey = n_nationkey +and p_name like '%green%') as profit +group by nation, o_year +order by nation, o_year desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE supplier index PRIMARY,i_s_nationkey i_s_nationkey 5 NULL 10 Using where; Using index; Using temporary; Using filesort +1 SIMPLE nation eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 +1 SIMPLE partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_suppkey 4 dbt3_s001.supplier.s_suppkey 70 +1 SIMPLE part eq_ref PRIMARY PRIMARY 4 dbt3_s001.partsupp.ps_partkey 1 Using where +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.supplier.s_suppkey 8 +1 SIMPLE orders eq_ref PRIMARY PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 +select nation, o_year, sum(amount) as sum_profit +from (select n_name as nation, +extract(year from o_orderdate) as o_year, +l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount +from part, supplier, lineitem, partsupp, orders, nation +where s_suppkey = l_suppkey and ps_suppkey = l_suppkey +and ps_partkey = l_partkey and p_partkey = l_partkey +and o_orderkey = l_orderkey and s_nationkey = n_nationkey +and p_name like '%green%') as profit +group by nation, o_year +order by nation, o_year desc; +nation o_year sum_profit +ARGENTINA 1997 18247.873399999993 +ARGENTINA 1996 7731.089399999995 +ARGENTINA 1995 134490.5697 +ARGENTINA 1994 36767.101500000004 +ARGENTINA 1993 35857.08 +ARGENTINA 1992 35740 +ETHIOPIA 1998 2758.7801999999992 +ETHIOPIA 1997 19419.294599999997 +ETHIOPIA 1995 51231.87439999999 +ETHIOPIA 1994 3578.9478999999974 +ETHIOPIA 1992 1525.8234999999986 +IRAN 1998 37817.229600000006 +IRAN 1997 52643.77359999999 +IRAN 1996 70143.7761 +IRAN 1995 84094.58260000001 +IRAN 1994 18140.925599999995 +IRAN 1993 78655.1676 +IRAN 1992 87142.23960000002 +IRAQ 1998 22860.8082 +IRAQ 1997 93676.24359999999 +IRAQ 1996 45103.3242 +IRAQ 1994 36010.728599999995 +IRAQ 1993 33221.9399 +IRAQ 1992 47755.05900000001 +KENYA 1998 44194.831999999995 +KENYA 1997 57578.36259999999 +KENYA 1996 59195.90210000001 +KENYA 1995 79262.6278 +KENYA 1994 102360.66609999999 +KENYA 1993 128422.0196 +KENYA 1992 181517.2089 +MOROCCO 1998 41797.823199999984 +MOROCCO 1997 23685.801799999994 +MOROCCO 1996 62115.19579999998 +MOROCCO 1995 42442.64300000001 +MOROCCO 1994 48655.878000000004 +MOROCCO 1993 22926.744400000003 +MOROCCO 1992 32239.8088 +PERU 1998 86999.36459999997 +PERU 1997 121110.41070000001 +PERU 1996 177040.40759999995 +PERU 1995 122247.94520000002 +PERU 1994 88046.25329999998 +PERU 1993 49379.813799999996 +PERU 1992 80646.86050000001 +UNITED KINGDOM 1998 50577.25560000001 +UNITED KINGDOM 1997 114288.8605 +UNITED KINGDOM 1996 147684.46480000002 +UNITED KINGDOM 1995 225267.65759999998 +UNITED KINGDOM 1994 140595.5864 +UNITED KINGDOM 1993 322548.49210000003 +UNITED KINGDOM 1992 67747.88279999999 +UNITED STATES 1998 3957.0431999999996 +UNITED STATES 1997 94729.5704 +UNITED STATES 1996 79297.85670000002 +UNITED STATES 1995 62201.23360000001 +UNITED STATES 1994 43075.629899999985 +UNITED STATES 1993 27168.486199999996 +UNITED STATES 1992 34092.366 +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; +EXPLAIN select o_orderkey, p_partkey +from part, lineitem, orders +where p_retailprice > 1100 and o_orderdate='1997-01-01' +and o_orderkey=l_orderkey and p_partkey=l_partkey; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE part range PRIMARY,i_p_retailprice i_p_retailprice 9 NULL 1 Using where; Using index +1 SIMPLE orders ref PRIMARY,i_o_orderdate i_o_orderdate 4 const 1 Using index +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey_partkey,i_l_partkey,i_l_orderkey,i_l_orderkey_quantity i_l_partkey 9 dbt3_s001.part.p_partkey,dbt3_s001.orders.o_orderkey 1 Using index +select o_orderkey, p_partkey +from part, lineitem, orders +where p_retailprice > 1100 and o_orderdate='1997-01-01' +and o_orderkey=l_orderkey and p_partkey=l_partkey; +o_orderkey p_partkey +5895 200 +set optimizer_switch=@save_optimizer_switch; +DROP DATABASE dbt3_s001; +use test; +set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test new file mode 100644 index 00000000000..cd896abebe1 --- /dev/null +++ b/mysql-test/t/stat_tables.test @@ -0,0 +1,108 @@ + +set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; + +set optimizer_use_stat_tables='preferably'; + +--disable_warnings +DROP DATABASE IF EXISTS dbt3_s001; +--enable_warnings + +CREATE DATABASE dbt3_s001; + +use dbt3_s001; + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/dbt3_s001.inc +create index i_p_retailprice on part(p_retailprice); +ANALYZE TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +FLUSH TABLES customer, lineitem, nation, orders, part, partsupp, region, supplier; +--enable_warnings +--enable_result_log +--enable_query_log + +select * from mysql.table_stat; +select * from mysql.index_stat; + + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; + +let $Q5= +select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey + and l_suppkey = s_suppkey and c_nationkey = s_nationkey + and s_nationkey = n_nationkey and n_regionkey = r_regionkey + and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; + +eval EXPLAIN $Q5; +eval $Q5; + +set optimizer_switch=@save_optimizer_switch; + + +let $Q8= +select o_year, + sum(case when nation = 'UNITED STATES' then volume else 0 end) / + sum(volume) as mkt_share +from (select extract(year from o_orderdate) as o_year, + l_extendedprice * (1-l_discount) as volume, + n2.n_name as nation + from part, supplier, lineitem, orders, customer, + nation n1, nation n2, region + where p_partkey = l_partkey and s_suppkey = l_suppkey + and l_orderkey = o_orderkey and o_custkey = c_custkey + and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey + and r_name = 'AMERICA' and s_nationkey = n2.n_nationkey + and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'STANDARD BRUSHED STEEL' ) as all_nations +group by o_year +order by o_year; + +eval EXPLAIN $Q8; +eval $Q8; + + +let $Q9= +select nation, o_year, sum(amount) as sum_profit +from (select n_name as nation, + extract(year from o_orderdate) as o_year, + l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount + from part, supplier, lineitem, partsupp, orders, nation + where s_suppkey = l_suppkey and ps_suppkey = l_suppkey + and ps_partkey = l_partkey and p_partkey = l_partkey + and o_orderkey = l_orderkey and s_nationkey = n_nationkey + and p_name like '%green%') as profit +group by nation, o_year +order by nation, o_year desc; + +eval EXPLAIN $Q9; +eval $Q9; + + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; + +let $QQ1= +select o_orderkey, p_partkey + from part, lineitem, orders + where p_retailprice > 1100 and o_orderdate='1997-01-01' + and o_orderkey=l_orderkey and p_partkey=l_partkey; + +eval EXPLAIN $QQ1; +eval $QQ1; + +set optimizer_switch=@save_optimizer_switch; + + +DROP DATABASE dbt3_s001; + +use test; + +set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; diff --git a/mysql-test/t/stat_tables_innodb.test b/mysql-test/t/stat_tables_innodb.test new file mode 100644 index 00000000000..e2ed647f49f --- /dev/null +++ b/mysql-test/t/stat_tables_innodb.test @@ -0,0 +1,7 @@ +--source include/have_innodb.inc + +SET SESSION STORAGE_ENGINE='InnoDB'; + +--source stat_tables.test + +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/sql/multi_range_read.cc b/sql/multi_range_read.cc index 7268491c0f4..036775cdf3e 100644 --- a/sql/multi_range_read.cc +++ b/sql/multi_range_read.cc @@ -1201,7 +1201,7 @@ bool DsMrr_impl::setup_buffer_sharing(uint key_size_in_keybuf, uint parts= my_count_bits(key_tuple_map); ulong rpc; ulonglong rowids_size= rowid_buf_elem_size; - if ((rpc= key_info->rec_per_key[parts - 1])) + if ((rpc= key_info->real_rec_per_key(parts - 1))) rowids_size= rowid_buf_elem_size * rpc; double fraction_for_rowids= diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 4b6df56d9a8..42a70094e2c 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -4869,11 +4869,6 @@ int mysqld_main(int argc, char **argv) check_performance_schema(); #endif -#if 0 - if (! opt_bootstrap) - init_stat_tables_usage(); -#endif - initialize_information_schema_acl(); execute_ddl_log_recovery(); diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 2e8b00982fc..61f73b95050 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -2875,7 +2875,7 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use, DBUG_PRINT("enter",("keys_to_use: %lu prev_tables: %lu const_tables: %lu", (ulong) keys_to_use.to_ulonglong(), (ulong) prev_tables, (ulong) const_tables)); - DBUG_PRINT("info", ("records: %lu", (ulong) head->file->stats.records)); + DBUG_PRINT("info", ("records: %lu", (ulong) head->stat_records())); delete quick; quick=0; needed_reg.clear_all(); @@ -2883,7 +2883,7 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use, DBUG_ASSERT(!head->is_filled_at_execution()); if (keys_to_use.is_clear_all() || head->is_filled_at_execution()) DBUG_RETURN(0); - records= head->file->stats.records; + records= head->stat_records(); if (!records) records++; /* purecov: inspected */ scan_time= (double) records / TIME_FOR_COMPARE + 1; @@ -3020,7 +3020,7 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use, if (group_trp) { param.table->quick_condition_rows= min(group_trp->records, - head->file->stats.records); + head->stat_records()); if (group_trp->read_cost < best_read_time) { best_trp= group_trp; @@ -4618,7 +4618,7 @@ TABLE_READ_PLAN *get_best_disjunct_quick(PARAM *param, SEL_IMERGE *imerge, DBUG_PRINT("info", ("index_merge scans cost %g", imerge_cost)); if (imerge_too_expensive || (imerge_cost > read_time) || ((non_cpk_scan_records+cpk_scan_records >= - param->table->file->stats.records) && + param->table->stat_records()) && read_time != DBL_MAX)) { /* @@ -4689,7 +4689,7 @@ TABLE_READ_PLAN *get_best_disjunct_quick(PARAM *param, SEL_IMERGE *imerge, imerge_trp->read_cost= imerge_cost; imerge_trp->records= non_cpk_scan_records + cpk_scan_records; imerge_trp->records= min(imerge_trp->records, - param->table->file->stats.records); + param->table->stat_records()); imerge_trp->range_scans= range_scans; imerge_trp->range_scans_end= range_scans + n_child_scans; read_time= imerge_cost; @@ -4760,7 +4760,7 @@ skip_to_ror_scan: ((TRP_ROR_INTERSECT*)(*cur_roru_plan))->index_scan_costs; roru_total_records += (*cur_roru_plan)->records; roru_intersect_part *= (*cur_roru_plan)->records / - param->table->file->stats.records; + param->table->stat_records(); } /* @@ -4770,7 +4770,7 @@ skip_to_ror_scan: in disjunction do not share key parts. */ roru_total_records -= (ha_rows)(roru_intersect_part* - param->table->file->stats.records); + param->table->stat_records()); /* ok, got a ROR read plan for each of the disjuncts Calculate cost: cost(index_union_scan(scan_1, ... scan_n)) = @@ -5047,12 +5047,12 @@ static inline ha_rows get_table_cardinality_for_index_intersect(TABLE *table) { if (table->file->ha_table_flags() & HA_STATS_RECORDS_IS_EXACT) - return table->file->stats.records; + return table->stat_records(); else { ha_rows d; double q; - for (q= (double)table->file->stats.records, d= 1 ; q >= 10; q/= 10, d*= 10 ) ; + for (q= (double)table->stat_records(), d= 1 ; q >= 10; q/= 10, d*= 10 ) ; return (ha_rows) (floor(q+0.5) * d); } } @@ -5455,9 +5455,8 @@ ha_rows records_in_index_intersect_extension(PARTIAL_INDEX_INTERSECT_INFO *curr, ha_rows ext_records= ext_index_scan->records; if (i < used_key_parts) { - ulong *rec_per_key= key_info->rec_per_key+i-1; - ulong f1= rec_per_key[0] ? rec_per_key[0] : 1; - ulong f2= rec_per_key[1] ? rec_per_key[1] : 1; + ulong f1= key_info->real_rec_per_key(i-1); + ulong f2= key_info->real_rec_per_key(i); ext_records= (ha_rows) ((double) ext_records / f2 * f1); } if (ext_records < table_cardinality) @@ -5949,7 +5948,7 @@ ROR_INTERSECT_INFO* ror_intersect_init(const PARAM *param) info->is_covering= FALSE; info->index_scan_costs= 0.0; info->index_records= 0; - info->out_rows= (double) param->table->file->stats.records; + info->out_rows= (double) param->table->stat_records(); bitmap_clear_all(&info->covered_fields); return info; } @@ -6075,7 +6074,7 @@ static double ror_scan_selectivity(const ROR_INTERSECT_INFO *info, min_range.flag= HA_READ_KEY_EXACT; max_range.key= key_val; max_range.flag= HA_READ_AFTER_KEY; - ha_rows prev_records= info->param->table->file->stats.records; + ha_rows prev_records= info->param->table->stat_records(); DBUG_ENTER("ror_scan_selectivity"); for (sel_arg= scan->sel_arg; sel_arg; @@ -6302,7 +6301,7 @@ TRP_ROR_INTERSECT *get_best_ror_intersect(const PARAM *param, SEL_TREE *tree, double min_cost= DBL_MAX; DBUG_ENTER("get_best_ror_intersect"); - if ((tree->n_ror_scans < 2) || !param->table->file->stats.records || + if ((tree->n_ror_scans < 2) || !param->table->stat_records() || !optimizer_flag(param->thd, OPTIMIZER_SWITCH_INDEX_MERGE_INTERSECT)) DBUG_RETURN(NULL); @@ -12570,14 +12569,14 @@ void cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts, double cpu_cost= 0; /* TODO: CPU cost of index_read calls? */ DBUG_ENTER("cost_group_min_max"); - table_records= table->file->stats.records; + table_records= table->stat_records(); keys_per_block= (table->file->stats.block_size / 2 / (index_info->key_length + table->file->ref_length) + 1); num_blocks= (uint)(table_records / keys_per_block) + 1; /* Compute the number of keys in a group. */ - keys_per_group= index_info->rec_per_key[group_key_parts - 1]; + keys_per_group= index_info->real_rec_per_key(group_key_parts - 1); if (keys_per_group == 0) /* If there is no statistics try to guess */ /* each group contains 10% of all records */ keys_per_group= (uint)(table_records / 10) + 1; @@ -12597,7 +12596,7 @@ void cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts, Compute the probability that two ends of a subgroup are inside different blocks. */ - keys_per_subgroup= index_info->rec_per_key[used_key_parts - 1]; + keys_per_subgroup= index_info->real_rec_per_key(used_key_parts - 1); if (keys_per_subgroup >= keys_per_block) /* If a subgroup is bigger than */ p_overlap= 1.0; /* a block, it will overlap at least two blocks. */ else diff --git a/sql/sql_base.h b/sql/sql_base.h index 5b88d53d231..203f8c18e14 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -315,6 +315,7 @@ int open_and_lock_tables_derived(THD *thd, TABLE_LIST *tables, bool derived); int read_statistics_for_table(THD *thd, TABLE *table); int collect_statistics_for_table(THD *thd, TABLE *table); int update_statistics_for_table(THD *thd, TABLE *table); +void set_statistics_for_table(THD *thd, TABLE *table); extern "C" int simple_raw_key_cmp(void* arg, const void* key1, const void* key2); diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index ff88bf7c0f8..351e38ec4f1 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -200,6 +200,7 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, #endif /* Update the table->file->stats.records number */ table->file->info(HA_STATUS_VARIABLE | HA_STATUS_NO_LOCK); + set_statistics_for_table(thd, table); table->covering_keys.clear_all(); table->quick_keys.clear_all(); // Can't use 'only index' diff --git a/sql/sql_join_cache.cc b/sql/sql_join_cache.cc index e0e1b175116..ba28cb8d0b0 100644 --- a/sql/sql_join_cache.cc +++ b/sql/sql_join_cache.cc @@ -3788,7 +3788,7 @@ uint JOIN_TAB_SCAN_MRR::aux_buffer_incr(ulong recno) uint incr= 0; TABLE_REF *ref= &join_tab->ref; TABLE *tab= join_tab->table; - uint rec_per_key= tab->key_info[ref->key].rec_per_key[ref->key_parts-1]; + uint rec_per_key= tab->key_info[ref->key].real_rec_per_key(ref->key_parts-1); set_if_bigger(rec_per_key, 1); if (recno == 1) incr= ref->key_length + tab->file->ref_length; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 35c45a9033c..9d8a4265260 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3121,6 +3121,7 @@ make_join_statistics(JOIN *join, List &tables_list, table_vector[i]=s->table=table=tables->table; table->pos_in_table_list= tables; error= tables->fetch_number_of_rows(); + set_statistics_for_table(join->thd, table); DBUG_EXECUTE_IF("bug11747970_raise_error", { @@ -3146,8 +3147,8 @@ make_join_statistics(JOIN *join, List &tables_list, s->dependent= tables->dep_tables; if (tables->schema_table) - table->file->stats.records= 2; - table->quick_condition_rows= table->file->stats.records; + table->file->stats.records= table->used_stat_records= 2; + table->quick_condition_rows= table->stat_records(); s->on_expr_ref= &tables->on_expr; if (*s->on_expr_ref) @@ -3155,10 +3156,10 @@ make_join_statistics(JOIN *join, List &tables_list, /* s is the only inner table of an outer join */ #ifdef WITH_PARTITION_STORAGE_ENGINE if (!table->is_filled_at_execution() && - (!table->file->stats.records || table->no_partitions_used) && !embedding) + (!table->stat_records() || table->no_partitions_used) && !embedding) #else if (!table->is_filled_at_execution() && - !table->file->stats.records && !embedding) + !table->stat_records() && !embedding) #endif { // Empty table s->dependent= 0; // Ignore LEFT JOIN depend. @@ -3205,7 +3206,7 @@ make_join_statistics(JOIN *join, List &tables_list, const bool no_partitions_used= FALSE; #endif if (!table->is_filled_at_execution() && - (table->s->system || table->file->stats.records <= 1 || + (table->s->system || table->stat_records() <= 1 || no_partitions_used) && !s->dependent && (table->file->ha_table_flags() & HA_STATS_RECORDS_IS_EXACT) && @@ -3387,7 +3388,7 @@ make_join_statistics(JOIN *join, List &tables_list, // All dep. must be constants if (s->dependent & ~(found_const_table_map)) continue; - if (table->file->stats.records <= 1L && + if (table->stat_records() <= 1L && (table->file->ha_table_flags() & HA_STATS_RECORDS_IS_EXACT) && !table->pos_in_table_list->embedding && !((outer_join & table->map) && @@ -5352,7 +5353,7 @@ best_access_path(JOIN *join, else { uint key_parts= table->actual_n_key_parts(keyinfo); - if (!(records=keyinfo->rec_per_key[key_parts-1])) + if (!(records= keyinfo->real_rec_per_key(key_parts-1))) { /* Prefer longer keys */ records= ((double) s->records / (double) rec * @@ -5452,7 +5453,7 @@ best_access_path(JOIN *join, else { /* Check if we have statistic about the distribution */ - if ((records= keyinfo->rec_per_key[max_key_part-1])) + if ((records= keyinfo->real_rec_per_key(max_key_part-1))) { /* Fix for the case where the index statistics is too @@ -7435,6 +7436,7 @@ static bool create_hj_key_for_table(JOIN *join, JOIN_TAB *join_tab, keyinfo->key_length=0; keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->flags= HA_GENERATED_KEY; + keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->name= (char *) "$hj"; keyinfo->rec_per_key= (ulong*) thd->calloc(sizeof(ulong)*key_parts); if (!keyinfo->rec_per_key) @@ -10006,7 +10008,7 @@ double JOIN_TAB::scan_time() } else { - found_records= records= table->file->stats.records; + found_records= records= table->stat_records(); read_time= table->file->scan_time(); /* table->quick_condition_rows has already been set to @@ -10017,7 +10019,7 @@ double JOIN_TAB::scan_time() } else { - found_records= records=table->file->stats.records; + found_records= records=table->stat_records(); read_time= found_records ? (double)found_records: 10.0;// TODO:fix this stub res= read_time; } @@ -14329,8 +14331,11 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->usable_key_parts=keyinfo->key_parts= param->group_parts; keyinfo->ext_key_parts= keyinfo->key_parts; keyinfo->key_length=0; - keyinfo->rec_per_key=0; + keyinfo->rec_per_key=NULL; + keyinfo->read_stat.avg_frequency= NULL; + keyinfo->write_stat.avg_frequency= NULL; keyinfo->algorithm= HA_KEY_ALG_UNDEF; + keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->name= (char*) "group_key"; ORDER *cur_group= group; for (; cur_group ; cur_group= cur_group->next, key_part_info++) @@ -14443,6 +14448,7 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->key_length= 0; // Will compute the sum of the parts below. keyinfo->name= (char*) "distinct_key"; keyinfo->algorithm= HA_KEY_ALG_UNDEF; + keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->rec_per_key=0; /* @@ -18211,7 +18217,7 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit, uint saved_best_key_parts= 0; int best_key_direction= 0; JOIN *join= tab->join; - ha_rows table_records= table->file->stats.records; + ha_rows table_records= table->stat_records(); test_if_cheaper_ordering(tab, order, table, usable_keys, ref_key, select_limit, @@ -18327,7 +18333,7 @@ check_reverse_order: { tab->ref.key= -1; tab->ref.key_parts= 0; - if (select_limit < table->file->stats.records) + if (select_limit < table->stat_records()) tab->limit= select_limit; } } @@ -18541,7 +18547,7 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order, if (!tab->preread_init_done && tab->preread_init()) goto err; if (table->s->tmp_table) - table->file->info(HA_STATUS_VARIABLE); // Get record count + table->file->info(HA_STATUS_VARIABLE); // Get record count table->sort.found_records=filesort(thd, table,join->sortorder, length, select, filesort_limit, 0, &examined_rows); @@ -21234,7 +21240,7 @@ static void select_describe(JOIN *join, bool need_tmp_table, bool need_order, handler->info(HA_STATUS_VARIABLE) has been called in make_join_statistics() */ - examined_rows= tab->table->file->stats.records; + examined_rows= tab->table->stat_records(); } } } @@ -22321,7 +22327,7 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, int best_key= -1; bool is_best_covering= FALSE; double fanout= 1; - ha_rows table_records= table->file->stats.records; + ha_rows table_records= table->stat_records(); bool group= join && join->group && order == join->group_list; ha_rows ref_key_quick_rows= HA_POS_ERROR; @@ -22411,7 +22417,7 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, if (used_key_parts > used_index_parts) used_pk_parts= used_key_parts-used_index_parts; rec_per_key= used_key_parts ? - keyinfo->rec_per_key[used_key_parts-1] : 1; + keyinfo->real_rec_per_key(used_key_parts-1) : 1; /* Take into account the selectivity of the used pk prefix */ if (used_pk_parts) { @@ -22426,8 +22432,8 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, rec_per_key= 1; if (rec_per_key > 1) { - rec_per_key*= pkinfo->rec_per_key[used_pk_parts-1]; - rec_per_key/= pkinfo->rec_per_key[0]; + rec_per_key*= pkinfo->real_rec_per_key(used_pk_parts-1); + rec_per_key/= pkinfo->real_rec_per_key(0); /* The value of rec_per_key for the extended key has to be adjusted accordingly if some components of @@ -22441,9 +22447,9 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, We presume here that for any index rec_per_key[i] != 0 if rec_per_key[0] != 0. */ - DBUG_ASSERT(pkinfo->rec_per_key[i]); - rec_per_key*= pkinfo->rec_per_key[i-1]; - rec_per_key/= pkinfo->rec_per_key[i]; + DBUG_ASSERT(pkinfo->real_rec_per_key(i)); + rec_per_key*= pkinfo->real_rec_per_key(i-1); + rec_per_key/= pkinfo->real_rec_per_key(i); } } } @@ -22488,7 +22494,7 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, select_limit= (ha_rows) (select_limit * (double) table_records / table->quick_condition_rows); - rec_per_key= keyinfo->rec_per_key[keyinfo->key_parts-1]; + rec_per_key= keyinfo->real_rec_per_key(keyinfo->key_parts-1); set_if_bigger(rec_per_key, 1); /* Here we take into account the fact that rows are @@ -22629,7 +22635,7 @@ uint get_index_for_order(ORDER *order, TABLE *table, SQL_SELECT *select, Update quick_condition_rows since single table UPDATE/DELETE procedures don't call make_join_statistics() and leave this variable uninitialized. */ - table->quick_condition_rows= table->file->stats.records; + table->quick_condition_rows= table->stat_records(); int key, direction; if (test_if_cheaper_ordering(NULL, order, table, diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 89f3c23d5af..27aa77ae1a3 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1531,7 +1531,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) now. */ -int read_statistics_for_table(THD *thd, struct TABLE *table) +int read_statistics_for_table(THD *thd, TABLE *table) { uint i; TABLE *stat_table; @@ -1579,6 +1579,29 @@ int read_statistics_for_table(THD *thd, struct TABLE *table) index_stat.set_key_fields(key_info, i+1); index_stat.get_stat_values(); } + + key_part_map ext_key_part_map= key_info->ext_key_part_map; + if (key_info->key_parts != key_info->ext_key_parts) + { + KEY *pk_key_info= table->key_info + table->s->primary_key; + uint k= key_info->key_parts; + double k_avg_frequency= key_info->read_stat.avg_frequency[k-1]; + uint pk_parts= pk_key_info->key_parts; + ha_rows n_rows= table->read_stat.cardinality; + for (uint j= 0; j < pk_parts; j++) + { + double avg_frequency; + if (!(ext_key_part_map & 1 << j)) + continue; + avg_frequency= pk_key_info->read_stat.avg_frequency[j]; + if (avg_frequency == 0 || + table->read_stat.cardinality_is_null) + avg_frequency= 1; + else if (avg_frequency > 1) + avg_frequency= max(k_avg_frequency * avg_frequency / n_rows, 1); + key_info->read_stat.avg_frequency[k++]= avg_frequency; + } + } } close_system_tables(thd, &open_tables_backup); @@ -1586,3 +1609,33 @@ int read_statistics_for_table(THD *thd, struct TABLE *table) DBUG_RETURN(0); } + +/** + @brief + Set statistics for a table that will be used by the optimizer + + @param + thd The thread handle + @param + table The table to set statistics for + + @details + Depending on the value of thd->variables.optimizer_use_stat_tables + the function performs the settings for the table that will control + from where the statistical data used by the optimizer will be taken. +*/ + +void set_statistics_for_table(THD *thd, TABLE *table) +{ + uint use_stat_table_mode= thd->variables.optimizer_use_stat_tables; + table->used_stat_records= + (use_stat_table_mode <= 1 || table->read_stat.cardinality_is_null) ? + table->file->stats.records : table->read_stat.cardinality; + KEY *key_info, *key_info_end; + for (key_info= table->key_info, key_info_end= key_info+table->s->keys; + key_info < key_info_end; key_info++) + { + key_info->is_statistics_from_stat_tables= + (use_stat_table_mode > 1 && key_info->read_stat.avg_frequency[0] > 0.5); + } +} diff --git a/sql/structs.h b/sql/structs.h index 51c71db7cd2..9949a72964b 100644 --- a/sql/structs.h +++ b/sql/structs.h @@ -96,6 +96,11 @@ typedef struct st_key { uint block_size; uint name_length; enum ha_key_alg algorithm; + /* + The flag is on if statistical data for the index prefixes + has to be taken from the system statistical tables. + */ + bool is_statistics_from_stat_tables; /* Note that parser is used when the table is opened for use, and parser_name is used when the table is being created. @@ -148,6 +153,15 @@ typedef struct st_key { /** reference to the list of options or NULL */ engine_option_value *option_list; ha_index_option_struct *option_struct; /* structure with parsed options */ + + inline double real_rec_per_key(uint i) + { + if (rec_per_key == 0) + return 0; + return (is_statistics_from_stat_tables ? + (ulong) (100 * read_stat.avg_frequency[i]) / (double) 100 : + (double) rec_per_key[i]); + } } KEY; diff --git a/sql/table.cc b/sql/table.cc index eb8d43deefa..6c20f95c28b 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -762,8 +762,8 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, ulong pos, record_offset; ulong *rec_per_key= NULL; ulong rec_buff_length; - double *read_avg_frequency= 0; - double *write_avg_frequency= 0; + double *read_avg_frequency= NULL; + double *write_avg_frequency= NULL; handler *handler_file= 0; KEY *keyinfo; KEY_PART_INFO *key_part= NULL; @@ -1019,6 +1019,8 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, { *key_part++= first_key_part[j]; *rec_per_key++= 0; + *read_avg_frequency++= 0; + *write_avg_frequency++= 0; keyinfo->ext_key_parts++; keyinfo->ext_key_part_map|= 1 << j; } @@ -2406,6 +2408,8 @@ int open_table_from_share(THD *thd, TABLE_SHARE *share, const char *alias, } #endif + outparam->read_stat.cardinality_is_null= TRUE; + if (!(field_ptr = (Field **) alloc_root(&outparam->mem_root, (uint) ((share->fields+1)* sizeof(Field*))))) @@ -5924,6 +5928,7 @@ bool TABLE::add_tmp_key(uint key, uint key_parts, keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->flags= HA_GENERATED_KEY; keyinfo->ext_key_flags= keyinfo->flags; + keyinfo->is_statistics_from_stat_tables= FALSE; if (unique) keyinfo->flags|= HA_NOSAME; sprintf(buf, "key%i", key); @@ -6619,6 +6624,7 @@ int TABLE_LIST::fetch_number_of_rows() { table->file->stats.records= ((select_union*)derived->result)->records; set_if_bigger(table->file->stats.records, 2); + table->used_stat_records= table->file->stats.records; } else error= table->file->info(HA_STATUS_VARIABLE | HA_STATUS_NO_LOCK); diff --git a/sql/table.h b/sql/table.h index e7f41576215..0deb793aa57 100644 --- a/sql/table.h +++ b/sql/table.h @@ -1025,6 +1025,9 @@ public: */ Table_statistics write_stat; + /* The estimate of the number of records in the table used by optimizer */ + ha_rows used_stat_records; + /* For each key that has quick_keys.is_set(key) == TRUE: estimate of #records and max #key parts that range access would use. @@ -1271,6 +1274,7 @@ public: bool update_const_key_parts(COND *conds); uint actual_n_key_parts(KEY *keyinfo); ulong actual_key_flags(KEY *keyinfo); + inline ha_rows stat_records() { return used_stat_records; } }; From 9f53c310d8fb76963d88e8a87a650d93469cdab2 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 19 Apr 2012 09:49:53 -0700 Subject: [PATCH 08/35] Fixed a problem for Q18 from DBT3/SF30 with innodb database instance: the server crashed when running the query with persistent statistics enabled. The field KEY::read_stat.avg_frequency must be initialized to NULL for the keys of temporary tables. --- sql/sql_select.cc | 1 + sql/sql_statistics.cc | 3 ++- sql/table.cc | 1 + 3 files changed, 4 insertions(+), 1 deletion(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 5279db17029..e482b6a8c96 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -14657,6 +14657,7 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->rec_per_key=0; + keyinfo->read_stat.avg_frequency= NULL; /* Create an extra field to hold NULL bits so that unique indexes on diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 27aa77ae1a3..3c6f5829e6b 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1636,6 +1636,7 @@ void set_statistics_for_table(THD *thd, TABLE *table) key_info < key_info_end; key_info++) { key_info->is_statistics_from_stat_tables= - (use_stat_table_mode > 1 && key_info->read_stat.avg_frequency[0] > 0.5); + (use_stat_table_mode > 1 && key_info->read_stat.avg_frequency && + key_info->read_stat.avg_frequency[0] > 0.5); } } diff --git a/sql/table.cc b/sql/table.cc index 78449d0498d..bbccd38d83c 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -5957,6 +5957,7 @@ bool TABLE::add_tmp_key(uint key, uint key_parts, if (!keyinfo->rec_per_key) return TRUE; bzero(keyinfo->rec_per_key, sizeof(ulong)*key_parts); + keyinfo->read_stat.avg_frequency= NULL; for (i= 0; i < key_parts; i++) { From 906c9a93a0da7df1e27d776d561c84c48ce7ee6d Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sun, 6 May 2012 22:42:14 -0700 Subject: [PATCH 09/35] Supported extended keys when collecting and using persistent statistics. --- mysql-test/r/stat_tables.result | 75 +++++++++++++++++++ mysql-test/r/stat_tables_innodb.result | 100 +++++++++++++++++++++++++ mysql-test/t/stat_tables.test | 31 +++++++- mysql-test/t/stat_tables_innodb.test | 5 ++ sql/sql_statistics.cc | 49 ++++++++---- 5 files changed, 246 insertions(+), 14 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 089c7871506..08fb5ee825e 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -3,6 +3,81 @@ set optimizer_use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1 +dbt3_s001 customer i_c_nationkey 1 6 +dbt3_s001 lineitem PRIMARY 1 4.003333333333333 +dbt3_s001 lineitem PRIMARY 2 1 +dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 +dbt3_s001 lineitem i_l_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey 1 600.5 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 +dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 +dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 +dbt3_s001 nation PRIMARY 1 1 +dbt3_s001 nation i_n_regionkey 1 5 +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 part PRIMARY 1 1 +dbt3_s001 part i_p_retailprice 1 1 +dbt3_s001 partsupp PRIMARY 1 3.5 +dbt3_s001 partsupp PRIMARY 2 1 +dbt3_s001 partsupp i_ps_partkey 1 3.5 +dbt3_s001 partsupp i_ps_suppkey 1 70 +dbt3_s001 region PRIMARY 1 1 +dbt3_s001 supplier PRIMARY 1 1 +dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +set optimizer_switch=@save_optimizer_switch; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_custkey i_o_orderdate 4 NULL 179 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE nation eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +1 SIMPLE supplier eq_ref PRIMARY,i_s_nationkey PRIMARY 4 dbt3_s001.lineitem.l_suppkey 1 Using where +select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +n_name revenue +PERU 321915.8715 +ARGENTINA 69817.1451 +set optimizer_switch=@save_optimizer_switch; +delete from mysql.index_stat; select * from mysql.table_stat; db_name table_name cardinality dbt3_s001 customer 150 diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 005e4c4828e..99e3a2ab083 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -1,9 +1,13 @@ SET SESSION STORAGE_ENGINE='InnoDB'; +set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; set optimizer_use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; select * from mysql.table_stat; db_name table_name cardinality dbt3_s001 customer 150 @@ -44,6 +48,101 @@ dbt3_s001 partsupp i_ps_suppkey 1 70 dbt3_s001 region PRIMARY 1 1 dbt3_s001 supplier PRIMARY 1 1 dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +set optimizer_switch=@save_optimizer_switch; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_custkey i_o_orderdate 4 NULL 211 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY,i_c_nationkey PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE nation eq_ref PRIMARY,i_n_regionkey PRIMARY 4 dbt3_s001.customer.c_nationkey 1 +1 SIMPLE supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.customer.c_nationkey 1 Using index +1 SIMPLE region ALL PRIMARY NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +1 SIMPLE lineitem ref PRIMARY,i_l_suppkey,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue +from customer, orders, lineitem, supplier, nation, region +where c_custkey = o_custkey and l_orderkey = o_orderkey +and l_suppkey = s_suppkey and c_nationkey = s_nationkey +and s_nationkey = n_nationkey and n_regionkey = r_regionkey +and r_name = 'AMERICA' and o_orderdate >= date '1995-01-01' + and o_orderdate < date '1995-01-01' + interval '1' year +group by n_name +order by revenue desc; +n_name revenue +PERU 321915.8715 +ARGENTINA 69817.1451 +set optimizer_switch=@save_optimizer_switch; +delete from mysql.index_stat; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1 +dbt3_s001 customer i_c_nationkey 1 6 +dbt3_s001 customer i_c_nationkey 2 1 +dbt3_s001 lineitem PRIMARY 1 4.003333333333333 +dbt3_s001 lineitem PRIMARY 2 1 +dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 +dbt3_s001 lineitem i_l_shipdate 2 1.014872401554842 +dbt3_s001 lineitem i_l_shipdate 3 1 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030065141139135 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1 +dbt3_s001 lineitem i_l_partkey 1 30.025 +dbt3_s001 lineitem i_l_partkey 2 1.008904569892473 +dbt3_s001 lineitem i_l_partkey 3 1 +dbt3_s001 lineitem i_l_suppkey 1 600.5 +dbt3_s001 lineitem i_l_suppkey 2 1.207277844792923 +dbt3_s001 lineitem i_l_suppkey 3 1 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 +dbt3_s001 lineitem i_l_receiptdate 2 1.0152155536770922 +dbt3_s001 lineitem i_l_receiptdate 3 1 +dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey 2 1 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1 +dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 +dbt3_s001 lineitem i_l_commitdate 2 1.036416983085951 +dbt3_s001 lineitem i_l_commitdate 3 1 +dbt3_s001 nation PRIMARY 1 1 +dbt3_s001 nation i_n_regionkey 1 5 +dbt3_s001 nation i_n_regionkey 2 1 +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_orderdate 2 1 +dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 orders i_o_custkey 2 1 +dbt3_s001 part PRIMARY 1 1 +dbt3_s001 part i_p_retailprice 1 1 +dbt3_s001 part i_p_retailprice 2 1 +dbt3_s001 partsupp PRIMARY 1 3.5 +dbt3_s001 partsupp PRIMARY 2 1 +dbt3_s001 partsupp i_ps_partkey 1 3.5 +dbt3_s001 partsupp i_ps_partkey 2 1 +dbt3_s001 partsupp i_ps_suppkey 1 70 +dbt3_s001 partsupp i_ps_suppkey 2 1 +dbt3_s001 region PRIMARY 1 1 +dbt3_s001 supplier PRIMARY 1 1 +dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +dbt3_s001 supplier i_s_nationkey 2 1 set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue @@ -228,4 +327,5 @@ set optimizer_switch=@save_optimizer_switch; DROP DATABASE dbt3_s001; use test; set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index cd896abebe1..aecb43fe763 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -10,15 +10,21 @@ DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; --disable_query_log --disable_result_log --disable_warnings --source include/dbt3_s001.inc create index i_p_retailprice on part(p_retailprice); +delete from mysql.table_stat; +delete from mysql.column_stat; +delete from mysql.index_stat; ANALYZE TABLE customer, lineitem, nation, orders, part, partsupp, region, supplier; -FLUSH TABLES customer, lineitem, nation, orders, part, partsupp, region, supplier; +FLUSH TABLE mysql.table_stat, mysql.index_stat; --enable_warnings --enable_result_log --enable_query_log @@ -26,6 +32,7 @@ FLUSH TABLES customer, lineitem, nation, orders, part, partsupp, region, supplie select * from mysql.table_stat; select * from mysql.index_stat; +set optimizer_switch=@save_optimizer_switch; set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; @@ -46,6 +53,28 @@ eval $Q5; set optimizer_switch=@save_optimizer_switch; +delete from mysql.index_stat; + +--disable_query_log +--disable_result_log +--disable_warnings +ANALYZE TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +FLUSH TABLE mysql.table_stat, mysql.index_stat; +--enable_warnings +--enable_result_log +--enable_query_log + +select * from mysql.table_stat; +select * from mysql.index_stat; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; + +eval EXPLAIN $Q5; +eval $Q5; + +set optimizer_switch=@save_optimizer_switch; let $Q8= select o_year, diff --git a/mysql-test/t/stat_tables_innodb.test b/mysql-test/t/stat_tables_innodb.test index e2ed647f49f..04e81de8f9d 100644 --- a/mysql-test/t/stat_tables_innodb.test +++ b/mysql-test/t/stat_tables_innodb.test @@ -2,6 +2,11 @@ SET SESSION STORAGE_ENGINE='InnoDB'; +set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; + --source stat_tables.test +set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; + SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 3c6f5829e6b..44f25115f00 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -768,7 +768,7 @@ public: */ void store_stat_fields() { - Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; + Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; double avg_frequency= table_key_info->write_stat.avg_frequency[prefix_arity-1]; if (avg_frequency == 0) @@ -984,7 +984,7 @@ public: { uint i; Prefix_calc_state *state; - uint key_parts= key_info->key_parts; + uint key_parts= table->actual_n_key_parts(key_info); empty= TRUE; prefixes= 0; if ((calc_state= @@ -1309,7 +1309,7 @@ int collect_statistics_for_table(THD *thd, TABLE *table) bitmap_set_all(table->read_set); /* Perform a full table scan to collect statistics on 'table's columns */ - if (!(rc= file->ha_rnd_init(FALSE))) + if (!(rc= file->ha_rnd_init(TRUE))) { while ((rc= file->ha_rnd_next(table->record[0])) != HA_ERR_END_OF_FILE) { @@ -1481,7 +1481,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) for (key_info= table->key_info, key_info_end= table->key_info+keys; key_info < key_info_end; key_info++) { - uint key_parts= key_info->key_parts; + uint key_parts= table->actual_n_key_parts(key_info); for (i= 0; i < key_parts; i++) { restore_record(stat_table, s->default_values); @@ -1573,33 +1573,56 @@ int read_statistics_for_table(THD *thd, TABLE *table) for (key_info= table->key_info, key_info_end= key_info+table->s->keys; key_info < key_info_end; key_info++) { - - for (i= 0; i < key_info->key_parts; i++) + uint key_parts= table->actual_n_key_parts(key_info); + for (i= 0; i < key_parts; i++) { index_stat.set_key_fields(key_info, i+1); index_stat.get_stat_values(); } key_part_map ext_key_part_map= key_info->ext_key_part_map; - if (key_info->key_parts != key_info->ext_key_parts) + if (key_info->key_parts != key_info->ext_key_parts && + key_info->read_stat.avg_frequency[key_info->key_parts] == 0) { + double *ptr; + double *ptr_end; KEY *pk_key_info= table->key_info + table->s->primary_key; uint k= key_info->key_parts; - double k_avg_frequency= key_info->read_stat.avg_frequency[k-1]; uint pk_parts= pk_key_info->key_parts; ha_rows n_rows= table->read_stat.cardinality; + double k_dist= n_rows / key_info->read_stat.avg_frequency[k-1]; + double *k_avg_freq_ptr= key_info->read_stat.avg_frequency + k; + uint m= 0; for (uint j= 0; j < pk_parts; j++) { - double avg_frequency; if (!(ext_key_part_map & 1 << j)) - continue; - avg_frequency= pk_key_info->read_stat.avg_frequency[j]; + { + for (ptr= k_avg_freq_ptr, ptr_end= ptr + m; ptr < ptr_end; ptr++) + { + double avg_frequency= pk_key_info->read_stat.avg_frequency[j-1]; + set_if_smaller(avg_frequency, 1); + (*ptr)*= pk_key_info->read_stat.avg_frequency[j]/avg_frequency; + } + } + else + { + key_info->read_stat.avg_frequency[k + m]= + pk_key_info->read_stat.avg_frequency[j]; + m++; + } + } + for (ptr= k_avg_freq_ptr, ptr_end= ptr + m; ptr < ptr_end; ptr++) + { + double avg_frequency= *ptr; if (avg_frequency == 0 || table->read_stat.cardinality_is_null) avg_frequency= 1; else if (avg_frequency > 1) - avg_frequency= max(k_avg_frequency * avg_frequency / n_rows, 1); - key_info->read_stat.avg_frequency[k++]= avg_frequency; + { + avg_frequency/= k_dist; + set_if_bigger(avg_frequency, 1); + } + *ptr= avg_frequency; } } } From 2a1afc29f252fb189f6e93a2e0d3a1939f8220d5 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 8 May 2012 16:42:55 -0700 Subject: [PATCH 10/35] Inverted the option --skip-stat-tables for --stat-tables. Set it to 0 by default. Now only the tests that use persistent statistics tables require starting the server with --stat-tables set on. --- mysql-test/include/have_stat_tables.inc | 5 +++++ mysql-test/include/have_stat_tables.opt | 1 + mysql-test/r/mysqld--help.result | 8 ++++---- mysql-test/t/stat_tables.test | 1 + mysql-test/t/statistics.test | 1 + sql/mysqld.cc | 12 ++++++------ sql/mysqld.h | 4 ++-- sql/sql_admin.cc | 2 +- sql/sql_base.cc | 2 +- 9 files changed, 22 insertions(+), 14 deletions(-) create mode 100644 mysql-test/include/have_stat_tables.inc create mode 100644 mysql-test/include/have_stat_tables.opt diff --git a/mysql-test/include/have_stat_tables.inc b/mysql-test/include/have_stat_tables.inc new file mode 100644 index 00000000000..97d0e44e39e --- /dev/null +++ b/mysql-test/include/have_stat_tables.inc @@ -0,0 +1,5 @@ +if (`select count(*) < 3 from information_schema.tables + where table_schema = 'mysql' and table_name in ('table_stat','column_stat','index_stat')`) +{ + --skip Needs stat tables +} diff --git a/mysql-test/include/have_stat_tables.opt b/mysql-test/include/have_stat_tables.opt new file mode 100644 index 00000000000..eb8f2d54ff6 --- /dev/null +++ b/mysql-test/include/have_stat_tables.opt @@ -0,0 +1 @@ +--stat-tables diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index 6b8ff4e5471..83fb6b566e2 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -720,9 +720,6 @@ The following options may be given as the first argument: --skip-show-database Don't allow 'SHOW DATABASE' commands --skip-slave-start If set, slave is not autostarted. - --skip-stat-tables Start without statistical tables. Statistical data on - table cardinalities, columns and indexes from these - tables become unavailable --skip-thread-priority Don't give threads different priorities. This option is deprecated because it has no effect; the implied behavior @@ -781,6 +778,9 @@ The following options may be given as the first argument: for the complete list of valid sql modes --stack-trace Print a symbolic stack trace on failure (Defaults to on; use --skip-stack-trace to disable.) + --stat-tables Start with statistical tables. Statistical data on table + cardinalities, columns and indexes from these tables + become available --stored-program-cache=# The soft upper limit for number of cached stored routines for one connection. @@ -1057,7 +1057,6 @@ skip-name-resolve FALSE skip-networking FALSE skip-show-database FALSE skip-slave-start FALSE -skip-stat-tables TRUE slave-compressed-protocol FALSE slave-exec-mode STRICT slave-net-timeout 3600 @@ -1070,6 +1069,7 @@ slow-query-log FALSE sort-buffer-size 2097152 sql-mode stack-trace TRUE +stat-tables FALSE stored-program-cache 256 symbolic-links FALSE sync-binlog 0 diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index aecb43fe763..47ec0696552 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -1,3 +1,4 @@ +--source include/have_stat_tables.inc set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 81108c9846d..7d1b207689c 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -1,3 +1,4 @@ +--source include/have_stat_tables.inc --source include/have_innodb.inc --disable_warnings drop table if exists t1,t2; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 7b7c73f147c..5da2bac74e3 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -446,7 +446,7 @@ ulong opt_replicate_events_marked_for_skip; */ volatile bool mqh_used = 0; my_bool opt_noacl; -my_bool opt_no_stat_tables; +my_bool opt_with_stat_tables; my_bool sp_automatic_privileges= 1; ulong opt_binlog_rows_event_max_size; @@ -6384,10 +6384,10 @@ struct my_option my_long_options[]= &opt_noacl, &opt_noacl, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0}, #endif - {"skip-stat-tables", OPT_SKIP_STAT_TABLES, - "Start without statistical tables. Statistical data on table cardinalities, " - "columns and indexes from these tables become unavailable", - &opt_no_stat_tables, &opt_no_stat_tables, 0, GET_BOOL, NO_ARG, + {"stat-tables", OPT_WITH_STAT_TABLES, + "Start with statistical tables. Statistical data on table cardinalities, " + "columns and indexes from these tables become available", + &opt_with_stat_tables, &opt_with_stat_tables, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0}, {"skip-host-cache", OPT_SKIP_HOST_CACHE, "Don't cache host names.", 0, 0, 0, GET_NO_ARG, NO_ARG, 0, 0, 0, 0, 0, 0}, @@ -7656,7 +7656,7 @@ mysqld_get_one_option(int optid, break; case OPT_BOOTSTRAP: opt_noacl=opt_bootstrap=1; - opt_no_stat_tables= 1; + opt_with_stat_tables= 0; break; case OPT_SERVER_ID: server_id_supplied = 1; diff --git a/sql/mysqld.h b/sql/mysqld.h index 6d2da80d7c8..35b395667e3 100644 --- a/sql/mysqld.h +++ b/sql/mysqld.h @@ -105,7 +105,7 @@ extern char* opt_secure_backup_file_priv; extern size_t opt_secure_backup_file_priv_len; extern my_bool opt_log_slow_admin_statements, opt_log_slow_slave_statements; extern my_bool sp_automatic_privileges, opt_noacl; -extern my_bool opt_no_stat_tables; +extern my_bool opt_with_stat_tables; extern my_bool opt_old_style_user_limits, trust_function_creators; extern uint opt_crash_binlog_innodb; extern char *shared_memory_base_name, *mysqld_unix_port; @@ -396,7 +396,7 @@ enum options_mysqld OPT_SKIP_PRIOR, OPT_SKIP_RESOLVE, OPT_SKIP_STACK_TRACE, - OPT_SKIP_STAT_TABLES, + OPT_WITH_STAT_TABLES, OPT_SKIP_SYMLINKS, OPT_SLOW_QUERY_LOG, OPT_SSL_CA, diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 46637bf10a4..c2d06a149e8 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -637,7 +637,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, DBUG_PRINT("admin", ("operator_func returned: %d", result_code)); } - if (operator_func == &handler::ha_analyze && !opt_no_stat_tables && + if (operator_func == &handler::ha_analyze && opt_with_stat_tables && thd->variables.optimizer_use_stat_tables > 0) { if (!(compl_result_code= diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 62db3b2e823..e1967c35031 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4625,7 +4625,7 @@ open_and_process_table(THD *thd, LEX *lex, TABLE_LIST *tables, goto end; } - if (!opt_no_stat_tables && thd->variables.optimizer_use_stat_tables > 0) + if (opt_with_stat_tables && thd->variables.optimizer_use_stat_tables > 0) { if (tables->table && tables->table->s && tables->table->s->table_category != TABLE_CATEGORY_SYSTEM) From 9b79feba56d8b0f955447afddbc4ab8b1d4d33c1 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 17 May 2012 16:54:26 -0700 Subject: [PATCH 11/35] Fixed the bug that caused displaying incorrect values in the column cardinality of the table information_schema.statistics. --- mysql-test/r/stat_tables.result | 35 ++++++++++++++++++++++++ mysql-test/r/stat_tables_innodb.result | 37 ++++++++++++++++++++++++++ mysql-test/t/stat_tables.test | 14 ++++++++++ sql/sql_select.cc | 1 + sql/sql_show.cc | 7 +++-- 5 files changed, 92 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 08fb5ee825e..df2c61498de 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -118,6 +118,41 @@ dbt3_s001 partsupp i_ps_suppkey 1 70 dbt3_s001 region PRIMARY 1 1 dbt3_s001 supplier PRIMARY 1 1 dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +select * from mysql.table_stat where table_name='orders'; +db_name table_name cardinality +dbt3_s001 orders 1500 +select * from mysql.index_stat where table_name='orders'; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_custkey 1 15 +select (select cardinality from mysql.table_stat where table_name='orders') / +(select avg_frequency from mysql.index_stat +where index_name='i_o_orderdate' and prefix_arity=1) as n_distinct; +n_distinct +1126 +select count(distinct o_orderdate) from orders; +count(distinct o_orderdate) +1126 +select (select cardinality from mysql.table_stat where table_name='orders') / +(select avg_frequency from mysql.index_stat +where index_name='i_o_custkey' and prefix_arity=1) as n_distinct; +n_distinct +100 +select count(distinct o_custkey) from orders; +count(distinct o_custkey) +100 +show index from orders; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +orders 0 PRIMARY 1 o_orderkey A 1500 NULL NULL BTREE +orders 1 i_o_orderdate 1 o_orderDATE A 1127 NULL NULL YES BTREE +orders 1 i_o_custkey 1 o_custkey A 100 NULL NULL YES BTREE +select index_name, column_name, cardinality from information_schema.statistics +where table_name='orders'; +index_name column_name cardinality +PRIMARY o_orderkey 1500 +i_o_orderdate o_orderDATE 1127 +i_o_custkey o_custkey 100 set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 99e3a2ab083..e59aaf1fc66 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -143,6 +143,43 @@ dbt3_s001 region PRIMARY 1 1 dbt3_s001 supplier PRIMARY 1 1 dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 dbt3_s001 supplier i_s_nationkey 2 1 +select * from mysql.table_stat where table_name='orders'; +db_name table_name cardinality +dbt3_s001 orders 1500 +select * from mysql.index_stat where table_name='orders'; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 orders PRIMARY 1 1 +dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 +dbt3_s001 orders i_o_orderdate 2 1 +dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 orders i_o_custkey 2 1 +select (select cardinality from mysql.table_stat where table_name='orders') / +(select avg_frequency from mysql.index_stat +where index_name='i_o_orderdate' and prefix_arity=1) as n_distinct; +n_distinct +1126 +select count(distinct o_orderdate) from orders; +count(distinct o_orderdate) +1126 +select (select cardinality from mysql.table_stat where table_name='orders') / +(select avg_frequency from mysql.index_stat +where index_name='i_o_custkey' and prefix_arity=1) as n_distinct; +n_distinct +100 +select count(distinct o_custkey) from orders; +count(distinct o_custkey) +100 +show index from orders; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +orders 0 PRIMARY 1 o_orderkey A 1500 NULL NULL BTREE +orders 1 i_o_orderdate 1 o_orderDATE A 1127 NULL NULL YES BTREE +orders 1 i_o_custkey 1 o_custkey A 100 NULL NULL YES BTREE +select index_name, column_name, cardinality from information_schema.statistics +where table_name='orders'; +index_name column_name cardinality +PRIMARY o_orderkey 1500 +i_o_orderdate o_orderDATE 1127 +i_o_custkey o_custkey 100 set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; EXPLAIN select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 47ec0696552..d85c93b6732 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -69,6 +69,20 @@ FLUSH TABLE mysql.table_stat, mysql.index_stat; select * from mysql.table_stat; select * from mysql.index_stat; +select * from mysql.table_stat where table_name='orders'; +select * from mysql.index_stat where table_name='orders'; +select (select cardinality from mysql.table_stat where table_name='orders') / + (select avg_frequency from mysql.index_stat + where index_name='i_o_orderdate' and prefix_arity=1) as n_distinct; +select count(distinct o_orderdate) from orders; +select (select cardinality from mysql.table_stat where table_name='orders') / + (select avg_frequency from mysql.index_stat + where index_name='i_o_custkey' and prefix_arity=1) as n_distinct; +select count(distinct o_custkey) from orders; +show index from orders; +select index_name, column_name, cardinality from information_schema.statistics + where table_name='orders'; + set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index e482b6a8c96..9aa44a5a417 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -14102,6 +14102,7 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, table->intersect_keys.init(); table->keys_in_use_for_query.init(); table->no_rows_with_nulls= param->force_not_null_cols; + table->read_stat.cardinality_is_null= TRUE; table->s= share; init_tmp_table_share(thd, share, "", 0, tmpname, tmpname); diff --git a/sql/sql_show.cc b/sql/sql_show.cc index b5ed327c193..ec0749f4693 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -5441,9 +5441,12 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, TABLE *show_table= tables->table; KEY *key_info=show_table->s->key_info; if (show_table->file) + { show_table->file->info(HA_STATUS_VARIABLE | HA_STATUS_NO_LOCK | HA_STATUS_TIME); + set_statistics_for_table(thd, show_table); + } for (uint i=0 ; i < show_table->s->keys ; i++,key_info++) { KEY_PART_INFO *key_part= key_info->key_part; @@ -5474,8 +5477,8 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, KEY *key=show_table->key_info+i; if (key->rec_per_key[j]) { - ha_rows records=(show_table->file->stats.records / - key->rec_per_key[j]); + ha_rows records=((double) show_table->stat_records() / + key->real_rec_per_key(j)); table->field[9]->store((longlong) records, TRUE); table->field[9]->set_notnull(); } From 055477ae522b805d3b2e890af9fe520cc1e3290d Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 22 May 2012 20:55:07 -0700 Subject: [PATCH 12/35] Support of the extended syntax for ANALYZE. --- mysql-test/r/statistics.result | 59 ++++++++++++++++++++++ mysql-test/t/statistics.test | 24 +++++++++ sql/sql_admin.cc | 68 ++++++++++++++++++++++++-- sql/sql_lex.cc | 2 + sql/sql_lex.h | 2 + sql/sql_statistics.cc | 27 +++++++---- sql/sql_yacc.yy | 89 +++++++++++++++++++++++++++++++++- 7 files changed, 255 insertions(+), 16 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 3a83f9ba66c..e4d6954c745 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -219,6 +219,65 @@ WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 3'; ARITY 1 ARITY 2 ARITY 3 6.2000 1.6875 1.1304 +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(); +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT * FROM table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +SELECT * FROM index_stat; +db_name table_name index_name prefix_arity avg_frequency +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT * FROM table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +SELECT * FROM index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS ALL INDEXES ALL; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT * FROM table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 CREATE TABLE t2 LIKE t1; ALTER TABLE t2 ENGINE=InnoDB; INSERT INTO t2 SELECT * FROM t1; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 7d1b207689c..e6764bb5744 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -181,6 +181,30 @@ SELECT WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 3'; +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(); +SELECT * FROM table_stat; +SELECT * FROM column_stat; +SELECT * FROM index_stat; + +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); +SELECT * FROM table_stat; +SELECT * FROM column_stat; +SELECT * FROM index_stat; + +DELETE FROM mysql.table_stat; +DELETE FROM mysql.column_stat; +DELETE FROM mysql.index_stat; + +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS ALL INDEXES ALL; + +SELECT * FROM table_stat; +SELECT * FROM column_stat; +SELECT * FROM index_stat; + CREATE TABLE t2 LIKE t1; ALTER TABLE t2 ENGINE=InnoDB; diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index c2d06a149e8..4e2581b885c 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -27,6 +27,7 @@ #include "sql_acl.h" // *_ACL #include "sp.h" // Sroutine_hash_entry #include "sql_parse.h" // check_table_access +#include "strfunc.h" #include "sql_admin.h" /* Prepare, run and cleanup for mysql_recreate_table() */ @@ -628,16 +629,75 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, } } - result_code= compl_result_code= 0; - if (operator_func != &handler::ha_analyze || - thd->variables.optimizer_use_stat_tables < 3) + result_code= compl_result_code= HA_ADMIN_OK; + + if (operator_func == &handler::ha_analyze) + { + TABLE *tab= table->table; + Field **field_ptr= tab->field; + + if (!lex->column_list) + { + uint fields= 0; + for ( ; *field_ptr; field_ptr++, fields++) ; + bitmap_set_prefix(tab->read_set, fields); + } + else + { + int pos; + LEX_STRING *column_name; + List_iterator_fast it(*lex->column_list); + + bitmap_clear_all(tab->read_set); + while ((column_name= it++)) + { + if (tab->s->fieldnames.type_names == 0 || + (pos= find_type(&tab->s->fieldnames, column_name->str, + column_name->length, 1)) <= 0) + { + compl_result_code= result_code= HA_ADMIN_INVALID; + break; + } + bitmap_set_bit(tab->read_set, --pos); + } + } + + if (!lex->index_list) + { + tab->keys_in_use_for_query.init(tab->s->keys); + } + else + { + int pos; + LEX_STRING *index_name; + List_iterator_fast it(*lex->index_list); + + tab->keys_in_use_for_query.clear_all(); + while ((index_name= it++)) + { + if (tab->s->keynames.type_names == 0 || + (pos= find_type(&tab->s->keynames, index_name->str, + index_name->length, 1)) <= 0) + { + compl_result_code= result_code= HA_ADMIN_INVALID; + break; + } + tab->keys_in_use_for_query.set_bit(--pos); + } + } + } + + if (result_code == HA_ADMIN_OK && + (operator_func != &handler::ha_analyze || + thd->variables.optimizer_use_stat_tables < 3)) { DBUG_PRINT("admin", ("calling operator_func '%s'", operator_name)); result_code = (table->table->file->*operator_func)(thd, check_opt); DBUG_PRINT("admin", ("operator_func returned: %d", result_code)); } - if (operator_func == &handler::ha_analyze && opt_with_stat_tables && + if (compl_result_code == HA_ADMIN_OK && + operator_func == &handler::ha_analyze && opt_with_stat_tables && thd->variables.optimizer_use_stat_tables > 0) { if (!(compl_result_code= diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 246f03a7754..bff3ebb3450 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -456,6 +456,8 @@ void lex_start(THD *thd) lex->set_var_list.empty(); lex->param_list.empty(); lex->view_list.empty(); + lex->column_list= NULL; + lex->index_list= NULL; lex->prepared_stmt_params.empty(); lex->auxiliary_table_list.empty(); lex->unit.next= lex->unit.master= diff --git a/sql/sql_lex.h b/sql/sql_lex.h index f1ee6cf22ec..70c97613f55 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -2383,6 +2383,8 @@ struct LEX: public Query_tables_list List set_var_list; // in-query assignment list List param_list; List view_list; // view list (list of field names in view) + List *column_list; // list of column names (in ANALYZE) + List *index_list; // list of index names (in ANALYZE) /* A stack of name resolution contexts for the query. This stack is used at parse time to set local name resolution contexts for various parts diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 44f25115f00..aeaecf537cb 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1289,6 +1289,8 @@ int collect_statistics_for_table(THD *thd, TABLE *table) { table_field= *field_ptr; uint max_heap_table_size= thd->variables.max_heap_table_size; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; set_nulls_for_write_column_stat_values(table_field); table_field->nulls= 0; table_field->column_total_length= 0; @@ -1306,8 +1308,6 @@ int collect_statistics_for_table(THD *thd, TABLE *table) table_field->count_distinct= NULL; } - bitmap_set_all(table->read_set); - /* Perform a full table scan to collect statistics on 'table's columns */ if (!(rc= file->ha_rnd_init(TRUE))) { @@ -1319,6 +1319,8 @@ int collect_statistics_for_table(THD *thd, TABLE *table) for (field_ptr= table->field; *field_ptr; field_ptr++) { table_field= *field_ptr; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; if (table_field->is_null()) table_field->nulls++; else @@ -1357,6 +1359,8 @@ int collect_statistics_for_table(THD *thd, TABLE *table) for (field_ptr= table->field; *field_ptr; field_ptr++) { table_field= *field_ptr; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; table_field->write_stat.nulls_ratio= (double) table_field->nulls/rows; table_field->write_stat.avg_length= (double) table_field->column_total_length / (rows-table_field->nulls); @@ -1380,12 +1384,13 @@ int collect_statistics_for_table(THD *thd, TABLE *table) if (!rc) { - uint keys= table->s->keys ; - + uint key; + key_map::Iterator it(table->keys_in_use_for_query); + /* Collect statistics for indexes */ - for (uint i= 0; i < keys; i++) + while ((key= it++) != key_map::Iterator::BITMAP_END) { - if ((rc= collect_statistics_for_index(table, i))) + if ((rc= collect_statistics_for_index(table, key))) break; } } @@ -1439,7 +1444,6 @@ int update_statistics_for_table(THD *thd, TABLE *table) int err; int rc= 0; TABLE *stat_table; - uint keys= table->s->keys; DBUG_ENTER("update_statistics_for_table"); @@ -1466,6 +1470,8 @@ int update_statistics_for_table(THD *thd, TABLE *table) for (Field **field_ptr= table->field; *field_ptr; field_ptr++) { Field *table_field= *field_ptr; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; restore_record(stat_table, s->default_values); column_stat.set_key_fields(table_field); err= column_stat.update_stat(); @@ -1475,12 +1481,13 @@ int update_statistics_for_table(THD *thd, TABLE *table) /* Update the statistical table index_stat */ stat_table= tables[INDEX_STAT].table; + uint key; + key_map::Iterator it(table->keys_in_use_for_query); Index_stat index_stat(stat_table, table); - KEY *key_info, *key_info_end; - for (key_info= table->key_info, key_info_end= table->key_info+keys; - key_info < key_info_end; key_info++) + while ((key= it++) != key_map::Iterator::BITMAP_END) { + KEY *key_info= table->key_info+key; uint key_parts= table->actual_n_key_parts(key_info); for (i= 0; i < key_parts; i++) { diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 34e015e1f9b..ff72d27647d 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1593,7 +1593,12 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); show describe load alter optimize keycache preload flush reset purge begin commit rollback savepoint release slave master_def master_defs master_file_def slave_until_opts - repair analyze check start checksum + repair analyze + analyze_table_list analyze_table_elem_spec + opt_persistent_stat_clause persistent_stat_spec + persistent_column_stat_spec persistent_index_stat_spec + table_column_list table_index_list + check start checksum field_list field_list_item field_spec kill column_def key_def keycache_list keycache_list_or_parts assign_to_keycache assign_to_keycache_parts @@ -7212,7 +7217,7 @@ analyze: /* Will be overriden during execution. */ YYPS->m_lock_type= TL_UNLOCK; } - table_list + analyze_table_list { THD *thd= YYTHD; LEX* lex= thd->lex; @@ -7223,6 +7228,86 @@ analyze: } ; +analyze_table_list: + analyze_table_elem_spec + | analyze_table_list ',' analyze_table_elem_spec + ; + +analyze_table_elem_spec: + table_name opt_persistent_stat_clause + ; + +opt_persistent_stat_clause: + /* empty */ + {} + | PERSISTENT_SYM FOR_SYM persistent_stat_spec + {} + ; + +persistent_stat_spec: + ALL + {} + | COLUMNS persistent_column_stat_spec INDEXES persistent_index_stat_spec + {} + +persistent_column_stat_spec: + ALL {} + | '(' + { + THD *thd= YYTHD; + LEX* lex= thd->lex; + lex->column_list= new List; + if (lex->column_list == NULL) + MYSQL_YYABORT; + } + table_column_list + ')' + ; + +persistent_index_stat_spec: + ALL {} + | '(' + { + THD *thd= YYTHD; + LEX* lex= thd->lex; + lex->index_list= new List; + if (lex->index_list == NULL) + MYSQL_YYABORT; + } + table_index_list + ')' + ; + +table_column_list: + /* empty */ + {} + | ident + { + Lex->column_list->push_back((LEX_STRING*) + sql_memdup(&$1, sizeof(LEX_STRING))); + } + | table_column_list ',' ident + { + Lex->column_list->push_back((LEX_STRING*) + sql_memdup(&$3, sizeof(LEX_STRING))); + } + ; + +table_index_list: + /* empty */ + {} + | ident + { + Lex->index_list->push_back((LEX_STRING*) + sql_memdup(&$1, sizeof(LEX_STRING))); + } + | table_index_list ',' ident + { + Lex->index_list->push_back((LEX_STRING*) + sql_memdup(&$3, sizeof(LEX_STRING))); + } + ; + binlog_base64_event: BINLOG_SYM TEXT_STRING_sys { From 6ac0363426f96c26c64447f0aa7fbd8a13ecc313 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 1 Jun 2012 11:23:53 -0700 Subject: [PATCH 13/35] An attempt to fix a buildbot failure with a test case from statistics.test that analyzes only some columns from a table. --- sql/sql_admin.cc | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 74cff57cce9..57eb2f98727 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -671,7 +671,8 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, break; } bitmap_set_bit(tab->read_set, --pos); - } + } + tab->file->column_bitmaps_signal(); } if (!lex->index_list) From 2ee14ef9c31c5db231bba0acc6d34ff18582353f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 1 Jun 2012 17:38:32 -0700 Subject: [PATCH 14/35] Fixed a buildbot failure with a testcase from statistics.test that analyzes only some columns from a table. --- sql/sql_admin.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 57eb2f98727..efb077f948d 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -670,7 +670,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, compl_result_code= result_code= HA_ADMIN_INVALID; break; } - bitmap_set_bit(tab->read_set, --pos); + bitmap_set_bit(tab->read_set, pos-1); } tab->file->column_bitmaps_signal(); } From f549f495f7f621d2c7e35303ab84392ec519ecb0 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 2 Jun 2012 17:19:01 -0700 Subject: [PATCH 15/35] Removed the server option --stat-tables. Renamed the system variable optimizer_use_stat_tables to use_stat_tables. This variable now has only 3 possible values: 'never', 'complementary', 'preferably'. If the server has been launched with --use-stat-tables='complementary'|'preferably' then the statictics tables can be employed by the optimizer and by the ANALYZE command. --- mysql-test/include/have_stat_tables.opt | 2 +- mysql-test/r/mysqld--help.result | 12 +- mysql-test/r/stat_tables.result | 6 +- mysql-test/r/stat_tables_innodb.result | 6 +- mysql-test/r/statistics.result | 14 +-- .../r/optimizer_use_stat_tables_basic.result | 116 ------------------ .../sys_vars/r/use_stat_tables_basic.result | 95 ++++++++++++++ .../t/optimizer_use_stat_tables_basic.test | 112 ----------------- .../sys_vars/t/use_stat_tables_basic.test | 100 +++++++++++++++ mysql-test/t/stat_tables.test | 6 +- mysql-test/t/statistics.test | 14 +-- sql/mysqld.cc | 9 +- sql/mysqld.h | 3 +- sql/sql_admin.cc | 8 +- sql/sql_base.cc | 2 +- sql/sql_class.h | 2 +- sql/sql_statistics.cc | 20 ++- sql/sys_vars.cc | 12 +- 18 files changed, 244 insertions(+), 295 deletions(-) delete mode 100644 mysql-test/suite/sys_vars/r/optimizer_use_stat_tables_basic.result create mode 100644 mysql-test/suite/sys_vars/r/use_stat_tables_basic.result delete mode 100644 mysql-test/suite/sys_vars/t/optimizer_use_stat_tables_basic.test create mode 100644 mysql-test/suite/sys_vars/t/use_stat_tables_basic.test diff --git a/mysql-test/include/have_stat_tables.opt b/mysql-test/include/have_stat_tables.opt index eb8f2d54ff6..addda71619d 100644 --- a/mysql-test/include/have_stat_tables.opt +++ b/mysql-test/include/have_stat_tables.opt @@ -1 +1 @@ ---stat-tables +--use-stat-tables='complementary' diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index 83fb6b566e2..7f4f220f698 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -493,9 +493,6 @@ The following options may be given as the first argument: partial_match_table_scan, semijoin, semijoin_with_cache, subquery_cache, table_elimination, extended_keys } and val is one of {on, off, default} - --optimizer-use-stat-tables=name - Specifies how to use system statistics tables. Possible - values are NEVER, COMPLEMENTARY, PREVERABLY, EXCLUSIVELY --performance-schema Enable the performance schema. --performance-schema-events-waits-history-long-size=# @@ -778,9 +775,6 @@ The following options may be given as the first argument: for the complete list of valid sql modes --stack-trace Print a symbolic stack trace on failure (Defaults to on; use --skip-stack-trace to disable.) - --stat-tables Start with statistical tables. Statistical data on table - cardinalities, columns and indexes from these tables - become available --stored-program-cache=# The soft upper limit for number of cached stored routines for one connection. @@ -838,6 +832,9 @@ The following options may be given as the first argument: Prohibit update of a VIEW, which does not contain a key of the underlying table and the query uses a LIMIT clause (usually get from GUI tools) + --use-stat-tables=name + Specifies how to use system statistics tables. Possible + values are NEVER, COMPLEMENTARY, PREVERABLY -u, --user=name Run mysqld daemon as user. --userstat Enables statistics gathering for USER_STATISTICS, CLIENT_STATISTICS, INDEX_STATISTICS and TABLE_STATISTICS @@ -996,7 +993,6 @@ old-style-user-limits FALSE optimizer-prune-level 1 optimizer-search-depth 62 optimizer-switch index_merge=on,index_merge_union=on,index_merge_sort_union=on,index_merge_intersection=on,index_merge_sort_intersection=off,engine_condition_pushdown=off,index_condition_pushdown=on,derived_merge=on,derived_with_keys=on,firstmatch=on,loosescan=on,materialization=on,in_to_exists=on,semijoin=on,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=on,mrr=off,mrr_cost_based=off,mrr_sort_keys=off,outer_join_with_cache=on,semijoin_with_cache=on,join_cache_incremental=on,join_cache_hashed=on,join_cache_bka=on,optimize_join_buffer_size=off,table_elimination=on -optimizer-use-stat-tables NEVER performance-schema FALSE performance-schema-events-waits-history-long-size 10000 performance-schema-events-waits-history-size 10 @@ -1069,7 +1065,6 @@ slow-query-log FALSE sort-buffer-size 2097152 sql-mode stack-trace TRUE -stat-tables FALSE stored-program-cache 256 symbolic-links FALSE sync-binlog 0 @@ -1091,6 +1086,7 @@ transaction-alloc-block-size 8192 transaction-isolation REPEATABLE-READ transaction-prealloc-size 4096 updatable-views-with-limit YES +use-stat-tables NEVER userstat FALSE verbose TRUE wait-timeout 28800 diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index df2c61498de..e52efc97c50 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -1,5 +1,5 @@ -set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; -set optimizer_use_stat_tables='preferably'; +set @save_use_stat_tables=@@use_stat_tables; +set use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; @@ -336,4 +336,4 @@ o_orderkey p_partkey set optimizer_switch=@save_optimizer_switch; DROP DATABASE dbt3_s001; use test; -set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index e59aaf1fc66..90361099ca2 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -1,8 +1,8 @@ SET SESSION STORAGE_ENGINE='InnoDB'; set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; set optimizer_switch='extended_keys=on'; -set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; -set optimizer_use_stat_tables='preferably'; +set @save_use_stat_tables=@@use_stat_tables; +set use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; @@ -363,6 +363,6 @@ o_orderkey p_partkey set optimizer_switch=@save_optimizer_switch; DROP DATABASE dbt3_s001; use test; -set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index e4d6954c745..4e1a5a6733c 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -1,5 +1,5 @@ drop table if exists t1,t2; -set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; +set @save_use_stat_tables=@@use_stat_tables; CREATE VIEW table_stat AS SELECT * FROM mysql.table_stat; CREATE VIEW column_stat AS @@ -16,7 +16,7 @@ CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; CREATE TABLE t1 ( a int NOT NULL PRIMARY KEY, b varchar(32), @@ -358,7 +358,7 @@ DROP TABLE t1,t2; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -set optimizer_use_stat_tables='never'; +set use_stat_tables='never'; set names utf8; CREATE DATABASE world; use world; @@ -387,7 +387,7 @@ Percentage float(3,1) NOT NULL default '0.0', PRIMARY KEY (Country, Language), INDEX (Percentage) ) CHARACTER SET utf8 COLLATE utf8_bin; -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; SELECT UPPER(db_name), UPPER(table_name), cardinality FROM test.table_stat; @@ -424,7 +424,7 @@ WORLD COUNTRYLANGUAGE PRIMARY 1 4.2232 WORLD COUNTRYLANGUAGE PRIMARY 2 1.0000 WORLD COUNTRYLANGUAGE Percentage 1 2.7640 use test; -set optimizer_use_stat_tables='never'; +set use_stat_tables='never'; CREATE DATABASE world_innodb; use world_innodb; CREATE TABLE Country ( @@ -455,7 +455,7 @@ INDEX (Percentage) ALTER TABLE Country ENGINE=InnoDB; ALTER TABLE City ENGINE=InnoDB; ALTER TABLE CountryLanguage ENGINE=InnoDB; -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; SELECT UPPER(db_name), UPPER(table_name), cardinality FROM test.table_stat; @@ -523,4 +523,4 @@ DELETE FROM mysql.index_stat; DROP VIEW test.table_stat; DROP VIEW test.column_stat; DROP VIEW test.index_stat; -set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/suite/sys_vars/r/optimizer_use_stat_tables_basic.result b/mysql-test/suite/sys_vars/r/optimizer_use_stat_tables_basic.result deleted file mode 100644 index 22c6859af62..00000000000 --- a/mysql-test/suite/sys_vars/r/optimizer_use_stat_tables_basic.result +++ /dev/null @@ -1,116 +0,0 @@ -SET @start_global_value = @@global.optimizer_use_stat_tables; -SELECT @start_global_value; -@start_global_value -NEVER -SET @start_session_value = @@session.optimizer_use_stat_tables; -SELECT @start_session_value; -@start_session_value -NEVER -SET @@global.optimizer_use_stat_tables = 2; -SET @@global.optimizer_use_stat_tables = DEFAULT; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -NEVER -SET @@session.optimizer_use_stat_tables = 3; -SET @@session.optimizer_use_stat_tables = DEFAULT; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -NEVER -SET @@global.optimizer_use_stat_tables = 0; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -NEVER -SET @@global.optimizer_use_stat_tables = 1; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -COMPLEMENTARY -SET @@global.optimizer_use_stat_tables = 2; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -PREFERABLY -SET @@global.optimizer_use_stat_tables = 3; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -EXCLUSIVELY -SET @@global.optimizer_use_stat_tables = NEVER; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -NEVER -SET @@global.optimizer_use_stat_tables = COMPLEMENTARY; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -COMPLEMENTARY -SET @@global.optimizer_use_stat_tables = PREFERABLY; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -PREFERABLY -SET @@global.optimizer_use_stat_tables = EXCLUSIVELY; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -EXCLUSIVELY -SET @@session.optimizer_use_stat_tables = 0; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -NEVER -SET @@session.optimizer_use_stat_tables = 1; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -COMPLEMENTARY -SET @@session.optimizer_use_stat_tables = 2; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -PREFERABLY -SET @@session.optimizer_use_stat_tables = 3; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -EXCLUSIVELY -SET @@session.optimizer_use_stat_tables = NEVER; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -NEVER -SET @@session.optimizer_use_stat_tables = PREFERABLY; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -PREFERABLY -SET @@session.optimizer_use_stat_tables = EXCLUSIVELY; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -EXCLUSIVELY -SET @@session.optimizer_use_stat_tables = COMPLEMENTARY; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -COMPLEMENTARY -set sql_mode=TRADITIONAL; -SET @@global.optimizer_use_stat_tables = 10; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of '10' -SET @@global.optimizer_use_stat_tables = -1024; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of '-1024' -SET @@global.optimizer_use_stat_tables = 2.4; -ERROR 42000: Incorrect argument type to variable 'optimizer_use_stat_tables' -SET @@global.optimizer_use_stat_tables = OFF; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of 'OFF' -SET @@session.optimizer_use_stat_tables = 10; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of '10' -SET @@session.optimizer_use_stat_tables = -2; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of '-2' -SET @@session.optimizer_use_stat_tables = 1.2; -ERROR 42000: Incorrect argument type to variable 'optimizer_use_stat_tables' -SET @@session.optimizer_use_stat_tables = ON; -ERROR 42000: Variable 'optimizer_use_stat_tables' can't be set to the value of 'ON' -SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES -WHERE VARIABLE_NAME='optimizer_use_stat_tables'; -VARIABLE_NAME VARIABLE_VALUE -OPTIMIZER_USE_STAT_TABLES EXCLUSIVELY -SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES -WHERE VARIABLE_NAME='optimizer_use_stat_tables'; -VARIABLE_NAME VARIABLE_VALUE -OPTIMIZER_USE_STAT_TABLES COMPLEMENTARY -SET @@global.optimizer_use_stat_tables = @start_global_value; -SELECT @@global.optimizer_use_stat_tables; -@@global.optimizer_use_stat_tables -NEVER -SET @@session.optimizer_use_stat_tables = @start_session_value; -SELECT @@session.optimizer_use_stat_tables; -@@session.optimizer_use_stat_tables -NEVER -set sql_mode=''; diff --git a/mysql-test/suite/sys_vars/r/use_stat_tables_basic.result b/mysql-test/suite/sys_vars/r/use_stat_tables_basic.result new file mode 100644 index 00000000000..64f6d868fa6 --- /dev/null +++ b/mysql-test/suite/sys_vars/r/use_stat_tables_basic.result @@ -0,0 +1,95 @@ +SET @start_global_value = @@global.use_stat_tables; +SELECT @start_global_value; +@start_global_value +NEVER +SET @start_session_value = @@session.use_stat_tables; +SELECT @start_session_value; +@start_session_value +NEVER +SET @@global.use_stat_tables = 2; +SET @@global.use_stat_tables = DEFAULT; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +NEVER +SET @@global.use_stat_tables = 0; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +NEVER +SET @@global.use_stat_tables = 1; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +COMPLEMENTARY +SET @@global.use_stat_tables = 2; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +PREFERABLY +SET @@global.use_stat_tables = NEVER; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +NEVER +SET @@global.use_stat_tables = COMPLEMENTARY; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +COMPLEMENTARY +SET @@global.use_stat_tables = PREFERABLY; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +PREFERABLY +SET @@session.use_stat_tables = 0; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +NEVER +SET @@session.use_stat_tables = 1; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +COMPLEMENTARY +SET @@session.use_stat_tables = 2; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +PREFERABLY +SET @@session.use_stat_tables = NEVER; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +NEVER +SET @@session.use_stat_tables = PREFERABLY; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +PREFERABLY +SET @@session.use_stat_tables = COMPLEMENTARY; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +COMPLEMENTARY +set sql_mode=TRADITIONAL; +SET @@global.use_stat_tables = 10; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of '10' +SET @@global.use_stat_tables = -1024; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of '-1024' +SET @@global.use_stat_tables = 2.4; +ERROR 42000: Incorrect argument type to variable 'use_stat_tables' +SET @@global.use_stat_tables = OFF; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of 'OFF' +SET @@session.use_stat_tables = 10; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of '10' +SET @@session.use_stat_tables = -2; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of '-2' +SET @@session.use_stat_tables = 1.2; +ERROR 42000: Incorrect argument type to variable 'use_stat_tables' +SET @@session.use_stat_tables = ON; +ERROR 42000: Variable 'use_stat_tables' can't be set to the value of 'ON' +SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='use_stat_tables'; +VARIABLE_NAME VARIABLE_VALUE +USE_STAT_TABLES PREFERABLY +SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='use_stat_tables'; +VARIABLE_NAME VARIABLE_VALUE +USE_STAT_TABLES COMPLEMENTARY +SET @@global.use_stat_tables = @start_global_value; +SELECT @@global.use_stat_tables; +@@global.use_stat_tables +NEVER +SET @@session.use_stat_tables = @start_session_value; +SELECT @@session.use_stat_tables; +@@session.use_stat_tables +NEVER +set sql_mode=''; diff --git a/mysql-test/suite/sys_vars/t/optimizer_use_stat_tables_basic.test b/mysql-test/suite/sys_vars/t/optimizer_use_stat_tables_basic.test deleted file mode 100644 index 6e0a96c403e..00000000000 --- a/mysql-test/suite/sys_vars/t/optimizer_use_stat_tables_basic.test +++ /dev/null @@ -1,112 +0,0 @@ ---source include/load_sysvars.inc - -############################################################# -# Save initial value # -############################################################# - -SET @start_global_value = @@global.optimizer_use_stat_tables; -SELECT @start_global_value; -SET @start_session_value = @@session.optimizer_use_stat_tables; -SELECT @start_session_value; - -############################################################### -# Display the DEFAULT value of optimizer_use_stat_tables # -############################################################### - -SET @@global.optimizer_use_stat_tables = 2; -SET @@global.optimizer_use_stat_tables = DEFAULT; -SELECT @@global.optimizer_use_stat_tables; - -SET @@session.optimizer_use_stat_tables = 3; -SET @@session.optimizer_use_stat_tables = DEFAULT; -SELECT @@session.optimizer_use_stat_tables; - - -################################################################################## -# Change the value ofoptimizer_use_stat_tables to a valid value for GLOBAL Scope # -################################################################################## - -SET @@global.optimizer_use_stat_tables = 0; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = 1; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = 2; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = 3; -SELECT @@global.optimizer_use_stat_tables; - -SET @@global.optimizer_use_stat_tables = NEVER; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = COMPLEMENTARY; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = PREFERABLY; -SELECT @@global.optimizer_use_stat_tables; -SET @@global.optimizer_use_stat_tables = EXCLUSIVELY; -SELECT @@global.optimizer_use_stat_tables; - -#################################################################################### -# Change the value of optimizer_use_stat_tables to a valid value for SESSION Scope # -#################################################################################### - -SET @@session.optimizer_use_stat_tables = 0; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = 1; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = 2; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = 3; -SELECT @@session.optimizer_use_stat_tables; - -SET @@session.optimizer_use_stat_tables = NEVER; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = PREFERABLY; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = EXCLUSIVELY; -SELECT @@session.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = COMPLEMENTARY; -SELECT @@session.optimizer_use_stat_tables; - -##################################################################### -# Change the value of optimizer_use_stat_tables to an invalid value # -##################################################################### -set sql_mode=TRADITIONAL; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@global.optimizer_use_stat_tables = 10; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@global.optimizer_use_stat_tables = -1024; ---Error ER_WRONG_TYPE_FOR_VAR -SET @@global.optimizer_use_stat_tables = 2.4; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@global.optimizer_use_stat_tables = OFF; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@session.optimizer_use_stat_tables = 10; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@session.optimizer_use_stat_tables = -2; ---Error ER_WRONG_TYPE_FOR_VAR -SET @@session.optimizer_use_stat_tables = 1.2; ---Error ER_WRONG_VALUE_FOR_VAR -SET @@session.optimizer_use_stat_tables = ON; - -############################################################################### -# Check if the value in GLOBAL & SESSION Tables matches value in variable # -############################################################################### - -SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES -WHERE VARIABLE_NAME='optimizer_use_stat_tables'; - -SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES -WHERE VARIABLE_NAME='optimizer_use_stat_tables'; - -#################################### -# Restore initial value # -#################################### - -SET @@global.optimizer_use_stat_tables = @start_global_value; -SELECT @@global.optimizer_use_stat_tables; -SET @@session.optimizer_use_stat_tables = @start_session_value; -SELECT @@session.optimizer_use_stat_tables; -set sql_mode=''; - -###################################################### -# END OF optimizer_use_stat_tables TESTS # -###################################################### \ No newline at end of file diff --git a/mysql-test/suite/sys_vars/t/use_stat_tables_basic.test b/mysql-test/suite/sys_vars/t/use_stat_tables_basic.test new file mode 100644 index 00000000000..7f526edf206 --- /dev/null +++ b/mysql-test/suite/sys_vars/t/use_stat_tables_basic.test @@ -0,0 +1,100 @@ +--source include/load_sysvars.inc + +############################################################# +# Save initial value # +############################################################# + +SET @start_global_value = @@global.use_stat_tables; +SELECT @start_global_value; +SET @start_session_value = @@session.use_stat_tables; +SELECT @start_session_value; + +############################################################### +# Display the DEFAULT value of use_stat_tables # +############################################################### + +SET @@global.use_stat_tables = 2; +SET @@global.use_stat_tables = DEFAULT; +SELECT @@global.use_stat_tables; + + +################################################################################## +# Change the value of use_stat_tables to a valid value for GLOBAL Scope # +################################################################################## + +SET @@global.use_stat_tables = 0; +SELECT @@global.use_stat_tables; +SET @@global.use_stat_tables = 1; +SELECT @@global.use_stat_tables; +SET @@global.use_stat_tables = 2; +SELECT @@global.use_stat_tables; + +SET @@global.use_stat_tables = NEVER; +SELECT @@global.use_stat_tables; +SET @@global.use_stat_tables = COMPLEMENTARY; +SELECT @@global.use_stat_tables; +SET @@global.use_stat_tables = PREFERABLY; +SELECT @@global.use_stat_tables; + +#################################################################################### +# Change the value of use_stat_tables to a valid value for SESSION Scope # +#################################################################################### + +SET @@session.use_stat_tables = 0; +SELECT @@session.use_stat_tables; +SET @@session.use_stat_tables = 1; +SELECT @@session.use_stat_tables; +SET @@session.use_stat_tables = 2; +SELECT @@session.use_stat_tables; + +SET @@session.use_stat_tables = NEVER; +SELECT @@session.use_stat_tables; +SET @@session.use_stat_tables = PREFERABLY; +SELECT @@session.use_stat_tables; +SET @@session.use_stat_tables = COMPLEMENTARY; +SELECT @@session.use_stat_tables; + +##################################################################### +# Change the value of use_stat_tables to an invalid value # +##################################################################### +set sql_mode=TRADITIONAL; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.use_stat_tables = 10; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.use_stat_tables = -1024; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.use_stat_tables = 2.4; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.use_stat_tables = OFF; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.use_stat_tables = 10; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.use_stat_tables = -2; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.use_stat_tables = 1.2; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.use_stat_tables = ON; + +############################################################################### +# Check if the value in GLOBAL & SESSION Tables matches value in variable # +############################################################################### + +SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='use_stat_tables'; + +SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='use_stat_tables'; + +#################################### +# Restore initial value # +#################################### + +SET @@global.use_stat_tables = @start_global_value; +SELECT @@global.use_stat_tables; +SET @@session.use_stat_tables = @start_session_value; +SELECT @@session.use_stat_tables; +set sql_mode=''; + +###################################################### +# END OF use_stat_tables TESTS # +###################################################### \ No newline at end of file diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index d85c93b6732..640f9febc75 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -1,8 +1,8 @@ --source include/have_stat_tables.inc -set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; +set @save_use_stat_tables=@@use_stat_tables; -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; --disable_warnings DROP DATABASE IF EXISTS dbt3_s001; @@ -149,4 +149,4 @@ DROP DATABASE dbt3_s001; use test; -set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index e6764bb5744..e4676c7b340 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -4,7 +4,7 @@ drop table if exists t1,t2; --enable_warnings -set @save_optimizer_use_stat_tables=@@optimizer_use_stat_tables; +set @save_use_stat_tables=@@use_stat_tables; CREATE VIEW table_stat AS SELECT * FROM mysql.table_stat; @@ -26,7 +26,7 @@ DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; CREATE TABLE t1 ( a int NOT NULL PRIMARY KEY, @@ -240,7 +240,7 @@ DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -set optimizer_use_stat_tables='never'; +set use_stat_tables='never'; set names utf8; @@ -258,7 +258,7 @@ use world; --enable_result_log --enable_query_log -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; --disable_result_log ANALYZE TABLE Country, City, CountryLanguage; @@ -275,7 +275,7 @@ SELECT UPPER(db_name), UPPER(table_name), use test; -set optimizer_use_stat_tables='never'; +set use_stat_tables='never'; CREATE DATABASE world_innodb; @@ -295,7 +295,7 @@ ALTER TABLE CountryLanguage ENGINE=InnoDB; --enable_result_log --enable_query_log -set optimizer_use_stat_tables='preferably'; +set use_stat_tables='preferably'; --disable_result_log ANALYZE TABLE Country, City, CountryLanguage; @@ -323,6 +323,6 @@ DROP VIEW test.table_stat; DROP VIEW test.column_stat; DROP VIEW test.index_stat; -set optimizer_use_stat_tables=@save_optimizer_use_stat_tables; +set use_stat_tables=@save_use_stat_tables; \ No newline at end of file diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 142070f3adb..cbed18f7ed8 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -446,7 +446,6 @@ ulong opt_replicate_events_marked_for_skip; */ volatile bool mqh_used = 0; my_bool opt_noacl; -my_bool opt_with_stat_tables; my_bool sp_automatic_privileges= 1; ulong opt_binlog_rows_event_max_size; @@ -3743,7 +3742,7 @@ static int init_common_variables() global_system_variables.character_set_results= default_charset_info; global_system_variables.character_set_client= default_charset_info; - global_system_variables.optimizer_use_stat_tables= 0; + global_system_variables.use_stat_tables= 0; if (!(character_set_filesystem= get_charset_by_csname(character_set_filesystem_name, @@ -6387,11 +6386,6 @@ struct my_option my_long_options[]= &opt_noacl, &opt_noacl, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0}, #endif - {"stat-tables", OPT_WITH_STAT_TABLES, - "Start with statistical tables. Statistical data on table cardinalities, " - "columns and indexes from these tables become available", - &opt_with_stat_tables, &opt_with_stat_tables, 0, GET_BOOL, NO_ARG, - 0, 0, 0, 0, 0, 0}, {"skip-host-cache", OPT_SKIP_HOST_CACHE, "Don't cache host names.", 0, 0, 0, GET_NO_ARG, NO_ARG, 0, 0, 0, 0, 0, 0}, {"skip-slave-start", 0, @@ -7659,7 +7653,6 @@ mysqld_get_one_option(int optid, break; case OPT_BOOTSTRAP: opt_noacl=opt_bootstrap=1; - opt_with_stat_tables= 0; break; case OPT_SERVER_ID: server_id_supplied = 1; diff --git a/sql/mysqld.h b/sql/mysqld.h index 35b395667e3..69348a45e9a 100644 --- a/sql/mysqld.h +++ b/sql/mysqld.h @@ -105,7 +105,7 @@ extern char* opt_secure_backup_file_priv; extern size_t opt_secure_backup_file_priv_len; extern my_bool opt_log_slow_admin_statements, opt_log_slow_slave_statements; extern my_bool sp_automatic_privileges, opt_noacl; -extern my_bool opt_with_stat_tables; +extern ulong use_stat_tables; extern my_bool opt_old_style_user_limits, trust_function_creators; extern uint opt_crash_binlog_innodb; extern char *shared_memory_base_name, *mysqld_unix_port; @@ -396,7 +396,6 @@ enum options_mysqld OPT_SKIP_PRIOR, OPT_SKIP_RESOLVE, OPT_SKIP_STACK_TRACE, - OPT_WITH_STAT_TABLES, OPT_SKIP_SYMLINKS, OPT_SLOW_QUERY_LOG, OPT_SSL_CA, diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index efb077f948d..8f811ab09dd 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -700,9 +700,7 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, } } - if (result_code == HA_ADMIN_OK && - (operator_func != &handler::ha_analyze || - thd->variables.optimizer_use_stat_tables < 3)) + if (result_code == HA_ADMIN_OK) { DBUG_PRINT("admin", ("calling operator_func '%s'", operator_name)); result_code = (table->table->file->*operator_func)(thd, check_opt); @@ -710,8 +708,8 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, } if (compl_result_code == HA_ADMIN_OK && - operator_func == &handler::ha_analyze && opt_with_stat_tables && - thd->variables.optimizer_use_stat_tables > 0) + operator_func == &handler::ha_analyze && + thd->variables.use_stat_tables > 0) { if (!(compl_result_code= collect_statistics_for_table(thd, table->table))) diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 66ae7b1cae2..704cfaa86cf 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4631,7 +4631,7 @@ open_and_process_table(THD *thd, LEX *lex, TABLE_LIST *tables, goto end; } - if (opt_with_stat_tables && thd->variables.optimizer_use_stat_tables > 0) + if (thd->variables.use_stat_tables > 0) { if (tables->table && tables->table->s && tables->table->s->table_category != TABLE_CATEGORY_SYSTEM) diff --git a/sql/sql_class.h b/sql/sql_class.h index 6272a08f9b2..3147c35c9fd 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -501,7 +501,7 @@ typedef struct system_variables ulong net_write_timeout; ulong optimizer_prune_level; ulong optimizer_search_depth; - ulong optimizer_use_stat_tables; + ulong use_stat_tables; ulong preload_buff_size; ulong profiling_history_size; ulong read_buff_size; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index aeaecf537cb..c2505cdc6ef 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -28,13 +28,13 @@ #include "sql_statistics.h" /* - The system variable 'optimizer_use_stat_tables' can take one of the + The system variable 'use_stat_tables' can take one of the following values: - "never", "complementary", "preferably", "exclusively". - If the values of the variable 'optimizer_use_stat_tables' is set to + "never", "complementary", "preferably". + If the values of the variable 'use_stat_tables' is set to "never then any statistical data from the persistent statistical tables is ignored by the optimizer. - If the value of the variable 'optimizer_use_stat_tables' is set to + If the value of the variable 'use_stat_tables' is set to "complementary" then a particular statistical characteristic is used by the optimizer only if the database engine does not provide similar statistics. For example, 'nulls_ratio' for table columns currently @@ -43,17 +43,13 @@ 'avg_frequency' for any index prefix from the statistical tables since the a similar statistical characteristic 'records_per_key' can be requested from the database engine. - If the value the variable 'optimizer_use_stat_tables' is set to + If the value the variable 'use_stat_tables' is set to "preferably" the optimizer uses a particular statistical data only if it can't be found in the statistical data. - If the value of the variable 'optimizer_use_stat_tables' is set to - "exclusively" the optimizer never uses statistical data that can be - returned by the database engine Only statistical data from the - statistical tables is used. If an ANALYZE command is executed then it results in collecting statistical data for the tables specified by the command and storing the collected statistics in the persistent statistical tables only - when the value of the variable 'optimizer_use_stat_tables' is not + when the value of the variable 'use_stat_tables' is not equal to "never". */ @@ -1650,14 +1646,14 @@ int read_statistics_for_table(THD *thd, TABLE *table) table The table to set statistics for @details - Depending on the value of thd->variables.optimizer_use_stat_tables + Depending on the value of thd->variables.use_stat_tables the function performs the settings for the table that will control from where the statistical data used by the optimizer will be taken. */ void set_statistics_for_table(THD *thd, TABLE *table) { - uint use_stat_table_mode= thd->variables.optimizer_use_stat_tables; + uint use_stat_table_mode= thd->variables.use_stat_tables; table->used_stat_records= (use_stat_table_mode <= 1 || table->read_stat.cardinality_is_null) ? table->file->stats.records : table->read_stat.cardinality; diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 78664398fa9..074832a4ff3 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -3748,14 +3748,14 @@ static Sys_var_ulong Sys_progress_report_time( SESSION_VAR(progress_report_time), CMD_LINE(REQUIRED_ARG), VALID_RANGE(0, UINT_MAX), DEFAULT(56), BLOCK_SIZE(1)); -const char *optimizer_use_stat_tables_modes[] = - {"NEVER", "COMPLEMENTARY", "PREFERABLY", "EXCLUSIVELY", 0}; +const char *use_stat_tables_modes[] = + {"NEVER", "COMPLEMENTARY", "PREFERABLY", 0}; static Sys_var_enum Sys_optimizer_use_stat_tables( - "optimizer_use_stat_tables", + "use_stat_tables", "Specifies how to use system statistics tables. Possible values are " - "NEVER, COMPLEMENTARY, PREVERABLY, EXCLUSIVELY", - SESSION_VAR(optimizer_use_stat_tables), CMD_LINE(REQUIRED_ARG), - optimizer_use_stat_tables_modes, DEFAULT(0)); + "NEVER, COMPLEMENTARY, PREVERABLY", + SESSION_VAR(use_stat_tables), CMD_LINE(REQUIRED_ARG), + use_stat_tables_modes, DEFAULT(0)); static Sys_var_mybool Sys_no_thread_alarm( "debug_no_thread_alarm", From 4ff6fd34dae6315384d8c38ea69092cde09b78ba Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 25 Jun 2012 22:33:07 -0700 Subject: [PATCH 16/35] Changed the type of all double columns in the system statistical tables mysql.column_stat, mysql.table_stat for the type DECIMAL(12,4). When cached the values from these columns are multiplied by factor 10^5 and stored as ulong numbers now. --- mysql-test/r/stat_tables.result | 126 ++++++------- mysql-test/r/stat_tables_innodb.result | 174 +++++++++--------- mysql-test/r/statistics.result | 80 ++++---- mysql-test/r/system_mysql_db.result | 8 +- .../suite/funcs_1/r/is_columns_mysql.result | 18 +- mysql-test/t/statistics.test | 84 ++++----- scripts/mysql_system_tables.sql | 4 +- sql/field.h | 49 ++++- sql/sql_select.cc | 6 +- sql/sql_statistics.cc | 70 +++---- sql/structs.h | 23 ++- sql/table.cc | 22 +-- 12 files changed, 339 insertions(+), 325 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index e52efc97c50..26f2b602c6b 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -17,34 +17,34 @@ dbt3_s001 region 5 dbt3_s001 supplier 10 select * from mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 customer PRIMARY 1 1 -dbt3_s001 customer i_c_nationkey 1 6 -dbt3_s001 lineitem PRIMARY 1 4.003333333333333 -dbt3_s001 lineitem PRIMARY 2 1 -dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 -dbt3_s001 lineitem i_l_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey 1 600.5 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 -dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 -dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 -dbt3_s001 nation PRIMARY 1 1 -dbt3_s001 nation i_n_regionkey 1 5 -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_custkey 1 15 -dbt3_s001 part PRIMARY 1 1 -dbt3_s001 part i_p_retailprice 1 1 -dbt3_s001 partsupp PRIMARY 1 3.5 -dbt3_s001 partsupp PRIMARY 2 1 -dbt3_s001 partsupp i_ps_partkey 1 3.5 -dbt3_s001 partsupp i_ps_suppkey 1 70 -dbt3_s001 region PRIMARY 1 1 -dbt3_s001 supplier PRIMARY 1 1 -dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 part i_p_retailprice 1 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 set optimizer_switch=@save_optimizer_switch; set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; @@ -90,47 +90,47 @@ dbt3_s001 region 5 dbt3_s001 supplier 10 select * from mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 customer PRIMARY 1 1 -dbt3_s001 customer i_c_nationkey 1 6 -dbt3_s001 lineitem PRIMARY 1 4.003333333333333 -dbt3_s001 lineitem PRIMARY 2 1 -dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 -dbt3_s001 lineitem i_l_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey 1 600.5 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 -dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 -dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 -dbt3_s001 nation PRIMARY 1 1 -dbt3_s001 nation i_n_regionkey 1 5 -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_custkey 1 15 -dbt3_s001 part PRIMARY 1 1 -dbt3_s001 part i_p_retailprice 1 1 -dbt3_s001 partsupp PRIMARY 1 3.5 -dbt3_s001 partsupp PRIMARY 2 1 -dbt3_s001 partsupp i_ps_partkey 1 3.5 -dbt3_s001 partsupp i_ps_suppkey 1 70 -dbt3_s001 region PRIMARY 1 1 -dbt3_s001 supplier PRIMARY 1 1 -dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 part i_p_retailprice 1 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 select * from mysql.table_stat where table_name='orders'; db_name table_name cardinality dbt3_s001 orders 1500 select * from mysql.index_stat where table_name='orders'; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_custkey 1 15 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 select (select cardinality from mysql.table_stat where table_name='orders') / (select avg_frequency from mysql.index_stat where index_name='i_o_orderdate' and prefix_arity=1) as n_distinct; n_distinct -1126 +1126.0416 select count(distinct o_orderdate) from orders; count(distinct o_orderdate) 1126 @@ -138,20 +138,20 @@ select (select cardinality from mysql.table_stat where table_name='orders') / (select avg_frequency from mysql.index_stat where index_name='i_o_custkey' and prefix_arity=1) as n_distinct; n_distinct -100 +100.0000 select count(distinct o_custkey) from orders; count(distinct o_custkey) 100 show index from orders; Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment orders 0 PRIMARY 1 o_orderkey A 1500 NULL NULL BTREE -orders 1 i_o_orderdate 1 o_orderDATE A 1127 NULL NULL YES BTREE +orders 1 i_o_orderdate 1 o_orderDATE A 1126 NULL NULL YES BTREE orders 1 i_o_custkey 1 o_custkey A 100 NULL NULL YES BTREE select index_name, column_name, cardinality from information_schema.statistics where table_name='orders'; index_name column_name cardinality PRIMARY o_orderkey 1500 -i_o_orderdate o_orderDATE 1127 +i_o_orderdate o_orderDATE 1126 i_o_custkey o_custkey 100 set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 90361099ca2..3d534dcab29 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -20,34 +20,34 @@ dbt3_s001 region 5 dbt3_s001 supplier 10 select * from mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 customer PRIMARY 1 1 -dbt3_s001 customer i_c_nationkey 1 6 -dbt3_s001 lineitem PRIMARY 1 4.003333333333333 -dbt3_s001 lineitem PRIMARY 2 1 -dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 -dbt3_s001 lineitem i_l_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey 1 600.5 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 -dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 -dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 -dbt3_s001 nation PRIMARY 1 1 -dbt3_s001 nation i_n_regionkey 1 5 -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_custkey 1 15 -dbt3_s001 part PRIMARY 1 1 -dbt3_s001 part i_p_retailprice 1 1 -dbt3_s001 partsupp PRIMARY 1 3.5 -dbt3_s001 partsupp PRIMARY 2 1 -dbt3_s001 partsupp i_ps_partkey 1 3.5 -dbt3_s001 partsupp i_ps_suppkey 1 70 -dbt3_s001 region PRIMARY 1 1 -dbt3_s001 supplier PRIMARY 1 1 -dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 part i_p_retailprice 1 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 set optimizer_switch=@save_optimizer_switch; set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; @@ -93,71 +93,71 @@ dbt3_s001 region 5 dbt3_s001 supplier 10 select * from mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 customer PRIMARY 1 1 -dbt3_s001 customer i_c_nationkey 1 6 -dbt3_s001 customer i_c_nationkey 2 1 -dbt3_s001 lineitem PRIMARY 1 4.003333333333333 -dbt3_s001 lineitem PRIMARY 2 1 -dbt3_s001 lineitem i_l_shipdate 1 2.650044130626655 -dbt3_s001 lineitem i_l_shipdate 2 1.014872401554842 -dbt3_s001 lineitem i_l_shipdate 3 1 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.025 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.57857142857143 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030065141139135 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1 -dbt3_s001 lineitem i_l_partkey 1 30.025 -dbt3_s001 lineitem i_l_partkey 2 1.008904569892473 -dbt3_s001 lineitem i_l_partkey 3 1 -dbt3_s001 lineitem i_l_suppkey 1 600.5 -dbt3_s001 lineitem i_l_suppkey 2 1.207277844792923 -dbt3_s001 lineitem i_l_suppkey 3 1 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477072310405645 -dbt3_s001 lineitem i_l_receiptdate 2 1.0152155536770922 -dbt3_s001 lineitem i_l_receiptdate 3 1 -dbt3_s001 lineitem i_l_orderkey 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey 2 1 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.003333333333333 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0403672903672905 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1 -dbt3_s001 lineitem i_l_commitdate 1 2.7159656264133876 -dbt3_s001 lineitem i_l_commitdate 2 1.036416983085951 -dbt3_s001 lineitem i_l_commitdate 3 1 -dbt3_s001 nation PRIMARY 1 1 -dbt3_s001 nation i_n_regionkey 1 5 -dbt3_s001 nation i_n_regionkey 2 1 -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_orderdate 2 1 -dbt3_s001 orders i_o_custkey 1 15 -dbt3_s001 orders i_o_custkey 2 1 -dbt3_s001 part PRIMARY 1 1 -dbt3_s001 part i_p_retailprice 1 1 -dbt3_s001 part i_p_retailprice 2 1 -dbt3_s001 partsupp PRIMARY 1 3.5 -dbt3_s001 partsupp PRIMARY 2 1 -dbt3_s001 partsupp i_ps_partkey 1 3.5 -dbt3_s001 partsupp i_ps_partkey 2 1 -dbt3_s001 partsupp i_ps_suppkey 1 70 -dbt3_s001 partsupp i_ps_suppkey 2 1 -dbt3_s001 region PRIMARY 1 1 -dbt3_s001 supplier PRIMARY 1 1 -dbt3_s001 supplier i_s_nationkey 1 1.1111111111111112 -dbt3_s001 supplier i_s_nationkey 2 1 +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 customer i_c_nationkey 2 1.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_shipdate 2 1.0149 +dbt3_s001 lineitem i_l_shipdate 3 1.0000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_receiptdate 2 1.0152 +dbt3_s001 lineitem i_l_receiptdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 nation i_n_regionkey 2 1.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_orderdate 2 1.0000 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 orders i_o_custkey 2 1.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 part i_p_retailprice 1 1.0000 +dbt3_s001 part i_p_retailprice 2 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_partkey 2 1.0000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 partsupp i_ps_suppkey 2 1.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 +dbt3_s001 supplier i_s_nationkey 2 1.0000 select * from mysql.table_stat where table_name='orders'; db_name table_name cardinality dbt3_s001 orders 1500 select * from mysql.index_stat where table_name='orders'; db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 orders PRIMARY 1 1 -dbt3_s001 orders i_o_orderdate 1 1.3321492007104796 -dbt3_s001 orders i_o_orderdate 2 1 -dbt3_s001 orders i_o_custkey 1 15 -dbt3_s001 orders i_o_custkey 2 1 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_orderdate 2 1.0000 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 orders i_o_custkey 2 1.0000 select (select cardinality from mysql.table_stat where table_name='orders') / (select avg_frequency from mysql.index_stat where index_name='i_o_orderdate' and prefix_arity=1) as n_distinct; n_distinct -1126 +1126.0416 select count(distinct o_orderdate) from orders; count(distinct o_orderdate) 1126 @@ -165,20 +165,20 @@ select (select cardinality from mysql.table_stat where table_name='orders') / (select avg_frequency from mysql.index_stat where index_name='i_o_custkey' and prefix_arity=1) as n_distinct; n_distinct -100 +100.0000 select count(distinct o_custkey) from orders; count(distinct o_custkey) 100 show index from orders; Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment orders 0 PRIMARY 1 o_orderkey A 1500 NULL NULL BTREE -orders 1 i_o_orderdate 1 o_orderDATE A 1127 NULL NULL YES BTREE +orders 1 i_o_orderdate 1 o_orderDATE A 1126 NULL NULL YES BTREE orders 1 i_o_custkey 1 o_custkey A 100 NULL NULL YES BTREE select index_name, column_name, cardinality from information_schema.statistics where table_name='orders'; index_name column_name cardinality PRIMARY o_orderkey 1500 -i_o_orderdate o_orderDATE 1127 +i_o_orderdate o_orderDATE 1126 i_o_custkey o_custkey 100 set @save_optimizer_switch=@@optimizer_switch; set optimizer_switch='index_condition_pushdown=off'; diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 4e1a5a6733c..99d3c04312b 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -1,18 +1,5 @@ drop table if exists t1,t2; set @save_use_stat_tables=@@use_stat_tables; -CREATE VIEW table_stat AS -SELECT * FROM mysql.table_stat; -CREATE VIEW column_stat AS -SELECT db_name, table_name, column_name, -min_value, max_value, -CAST(nulls_ratio AS decimal(12,4)) AS 'nulls_ratio', -CAST(avg_length AS decimal(12,4)) AS 'avg_length', -CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' - FROM mysql.column_stat; -CREATE VIEW index_stat AS -SELECT db_name, table_name, index_name, prefix_arity, -CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' - FROM mysql.index_stat; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; @@ -73,10 +60,10 @@ INSERT INTO t1 VALUES ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK -SELECT * FROM table_stat; +SELECT * FROM mysql.table_stat; db_name table_name cardinality test t1 40 -SELECT * FROM column_stat; +SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 @@ -84,7 +71,7 @@ test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 -SELECT * FROM index_stat; +SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 test t1 idx1 1 6.4000 @@ -98,7 +85,7 @@ test t1 idx4 3 1.1304 SELECT COUNT(*) FROM t1; COUNT(*) 40 -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='a'; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 @@ -110,7 +97,7 @@ SELECT MIN(t1.a), MAX(t1.a), FROM t1; MIN(t1.a) MAX(t1.a) NULLS_RATIO(t1.a) AVG_FREQUENCY(t1.a) 0 49 0.2000 1.0000 -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='b'; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 @@ -122,7 +109,7 @@ SELECT MIN(t1.b), MAX(t1.b), FROM t1; MIN(t1.b) MAX(t1.b) NULLS_RATIO(t1.b) AVG_FREQUENCY(t1.b) vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='c'; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 @@ -134,7 +121,7 @@ SELECT MIN(t1.c), MAX(t1.c), FROM t1; MIN(t1.c) MAX(t1.c) NULLS_RATIO(t1.c) AVG_FREQUENCY(t1.c) aaaa dddddddd 0.1250 7.0000 -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='d'; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 @@ -146,7 +133,7 @@ SELECT MIN(t1.d), MAX(t1.d), FROM t1; MIN(t1.d) MAX(t1.d) NULLS_RATIO(t1.d) AVG_FREQUENCY(t1.d) 1989-03-12 1999-07-23 0.1500 8.5000 -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='e'; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 e 0.01 0.112 0.2250 8.0000 6.2000 @@ -158,7 +145,7 @@ SELECT MIN(t1.e), MAX(t1.e), FROM t1; MIN(t1.e) MAX(t1.e) NULLS_RATIO(t1.e) AVG_FREQUENCY(t1.e) 0.01 0.112 0.2250 6.2000 -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx1'; db_name table_name index_name prefix_arity avg_frequency test t1 idx1 1 6.4000 @@ -173,7 +160,7 @@ WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) AS 'ARITY 2'; ARITY 1 ARITY 2 6.4000 1.6875 -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx2'; db_name table_name index_name prefix_arity avg_frequency test t1 idx2 1 7.0000 @@ -188,7 +175,7 @@ WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 2'; ARITY 1 ARITY 2 7.0000 2.3846 -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx3'; db_name table_name index_name prefix_arity avg_frequency test t1 idx3 1 8.5000 @@ -198,7 +185,7 @@ SELECT AS 'ARITY 1'; ARITY 1 8.5000 -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx4'; db_name table_name index_name prefix_arity avg_frequency test t1 idx4 1 6.2000 @@ -225,25 +212,25 @@ DELETE FROM mysql.index_stat; ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(); Table Op Msg_type Msg_text test.t1 analyze status Table is already up to date -SELECT * FROM table_stat; +SELECT * FROM mysql.table_stat; db_name table_name cardinality test t1 40 -SELECT * FROM column_stat; +SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -SELECT * FROM index_stat; +SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); Table Op Msg_type Msg_text test.t1 analyze status Table is already up to date -SELECT * FROM table_stat; +SELECT * FROM mysql.table_stat; db_name table_name cardinality test t1 40 -SELECT * FROM column_stat; +SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 -SELECT * FROM index_stat; +SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 idx2 1 7.0000 test t1 idx2 2 2.3846 @@ -256,10 +243,10 @@ DELETE FROM mysql.index_stat; ANALYZE TABLE t1 PERSISTENT FOR COLUMNS ALL INDEXES ALL; Table Op Msg_type Msg_text test.t1 analyze status Table is already up to date -SELECT * FROM table_stat; +SELECT * FROM mysql.table_stat; db_name table_name cardinality test t1 40 -SELECT * FROM column_stat; +SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 @@ -267,7 +254,7 @@ test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 -SELECT * FROM index_stat; +SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 test t1 idx1 1 6.4000 @@ -284,11 +271,11 @@ INSERT INTO t2 SELECT * FROM t1; ANALYZE TABLE t2; Table Op Msg_type Msg_text test.t2 analyze status OK -SELECT * FROM table_stat; +SELECT * FROM mysql.table_stat; db_name table_name cardinality test t1 40 test t2 40 -SELECT * FROM column_stat ORDER BY column_name; +SELECT * FROM mysql.column_stat ORDER BY column_name; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 test t2 a 0 49 0.0000 4.0000 1.0000 @@ -302,7 +289,7 @@ test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t2 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 test t2 f 1 5 0.2000 1.0000 6.4000 -SELECT * FROM index_stat ORDER BY index_name, prefix_arity, table_name; +SELECT * FROM mysql.index_stat ORDER BY index_name, prefix_arity, table_name; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 test t2 PRIMARY 1 1.0000 @@ -335,7 +322,7 @@ ADD INDEX idx4 (e, b(4), d); ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK -SELECT * FROM column_stat; +SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 test t1 b NULL NULL 0.2000 17.1250 NULL @@ -343,7 +330,7 @@ test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 -SELECT * FROM index_stat; +SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 test t1 idx2 1 7.0000 @@ -390,14 +377,14 @@ INDEX (Percentage) set use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; SELECT UPPER(db_name), UPPER(table_name), cardinality -FROM test.table_stat; +FROM mysql.table_stat; UPPER(db_name) UPPER(table_name) cardinality WORLD COUNTRY 239 WORLD CITY 4079 WORLD COUNTRYLANGUAGE 984 SELECT UPPER(db_name), UPPER(table_name), column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency -FROM test.column_stat; +FROM mysql.column_stat; UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency WORLD COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 WORLD COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 @@ -413,7 +400,7 @@ WORLD COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 WORLD COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 SELECT UPPER(db_name), UPPER(table_name), index_name, prefix_arity, avg_frequency -FROM test.index_stat; +FROM mysql.index_stat; UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency WORLD COUNTRY PRIMARY 1 1.0000 WORLD COUNTRY Name 1 1.0000 @@ -458,7 +445,7 @@ ALTER TABLE CountryLanguage ENGINE=InnoDB; set use_stat_tables='preferably'; ANALYZE TABLE Country, City, CountryLanguage; SELECT UPPER(db_name), UPPER(table_name), cardinality -FROM test.table_stat; +FROM mysql.table_stat; UPPER(db_name) UPPER(table_name) cardinality WORLD COUNTRY 239 WORLD CITY 4079 @@ -468,7 +455,7 @@ WORLD_INNODB CITY 4079 WORLD_INNODB COUNTRYLANGUAGE 984 SELECT UPPER(db_name), UPPER(table_name), column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency -FROM test.column_stat; +FROM mysql.column_stat; UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency WORLD COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 WORLD COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 @@ -496,7 +483,7 @@ WORLD_INNODB COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 WORLD_INNODB COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 SELECT UPPER(db_name), UPPER(table_name), index_name, prefix_arity, avg_frequency -FROM test.index_stat; +FROM mysql.index_stat; UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency WORLD COUNTRY PRIMARY 1 1.0000 WORLD COUNTRY Name 1 1.0000 @@ -520,7 +507,4 @@ DROP DATABASE world_innodb; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -DROP VIEW test.table_stat; -DROP VIEW test.column_stat; -DROP VIEW test.index_stat; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/system_mysql_db.result b/mysql-test/r/system_mysql_db.result index 985fbd0539d..cf7db8f64ff 100644 --- a/mysql-test/r/system_mysql_db.result +++ b/mysql-test/r/system_mysql_db.result @@ -283,9 +283,9 @@ column_stat CREATE TABLE `column_stat` ( `column_name` varchar(64) COLLATE utf8_bin NOT NULL, `min_value` varchar(255) COLLATE utf8_bin DEFAULT NULL, `max_value` varchar(255) COLLATE utf8_bin DEFAULT NULL, - `nulls_ratio` double DEFAULT NULL, - `avg_length` double DEFAULT NULL, - `avg_frequency` double DEFAULT NULL, + `nulls_ratio` decimal(12,4) DEFAULT NULL, + `avg_length` decimal(12,4) DEFAULT NULL, + `avg_frequency` decimal(12,4) DEFAULT NULL, PRIMARY KEY (`db_name`,`table_name`,`column_name`) ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Columns' show create table index_stat; @@ -295,7 +295,7 @@ index_stat CREATE TABLE `index_stat` ( `table_name` varchar(64) COLLATE utf8_bin NOT NULL, `index_name` varchar(64) COLLATE utf8_bin NOT NULL, `prefix_arity` int(11) unsigned NOT NULL, - `avg_frequency` double DEFAULT NULL, + `avg_frequency` decimal(12,4) DEFAULT NULL, PRIMARY KEY (`db_name`,`table_name`,`index_name`,`prefix_arity`) ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Indexes' show tables; diff --git a/mysql-test/suite/funcs_1/r/is_columns_mysql.result b/mysql-test/suite/funcs_1/r/is_columns_mysql.result index c83f80cd28f..bc8be53d524 100644 --- a/mysql-test/suite/funcs_1/r/is_columns_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_columns_mysql.result @@ -9,13 +9,13 @@ def mysql columns_priv Host 1 NO char 60 180 NULL NULL NULL utf8 utf8_bin char( def mysql columns_priv Table_name 4 NO char 64 192 NULL NULL NULL utf8 utf8_bin char(64) PRI select,insert,update,references def mysql columns_priv Timestamp 6 CURRENT_TIMESTAMP NO timestamp NULL NULL NULL NULL 0 NULL NULL timestamp on update CURRENT_TIMESTAMP select,insert,update,references def mysql columns_priv User 3 NO char 16 48 NULL NULL NULL utf8 utf8_bin char(16) PRI select,insert,update,references -def mysql column_stat avg_frequency 8 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references -def mysql column_stat avg_length 7 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +def mysql column_stat avg_frequency 8 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references +def mysql column_stat avg_length 7 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references def mysql column_stat column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql column_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql column_stat max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references def mysql column_stat min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references -def mysql column_stat nulls_ratio 6 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +def mysql column_stat nulls_ratio 6 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references def mysql column_stat table_name 2 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql db Alter_priv 13 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references def mysql db Alter_routine_priv 19 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references @@ -105,7 +105,7 @@ def mysql host Select_priv 3 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci e def mysql host Show_view_priv 16 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references def mysql host Trigger_priv 20 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references def mysql host Update_priv 5 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') select,insert,update,references -def mysql index_stat avg_frequency 5 NULL YES double NULL NULL 22 NULL NULL NULL NULL double select,insert,update,references +def mysql index_stat avg_frequency 5 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references def mysql index_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql index_stat index_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql index_stat prefix_arity 4 NULL NO int NULL NULL 10 0 NULL NULL NULL int(11) unsigned PRI select,insert,update,references @@ -291,7 +291,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME NULL bigint NULL NULL NULL datetime NULL NULL -NULL double NULL NULL +NULL decimal NULL NULL NULL int NULL NULL NULL smallint NULL NULL NULL time NULL NULL @@ -325,9 +325,9 @@ NULL mysql columns_priv Timestamp timestamp NULL NULL NULL NULL timestamp 3.0000 mysql column_stat column_name varchar 64 192 utf8 utf8_bin varchar(64) 3.0000 mysql column_stat min_value varchar 255 765 utf8 utf8_bin varchar(255) 3.0000 mysql column_stat max_value varchar 255 765 utf8 utf8_bin varchar(255) -NULL mysql column_stat nulls_ratio double NULL NULL NULL NULL double -NULL mysql column_stat avg_length double NULL NULL NULL NULL double -NULL mysql column_stat avg_frequency double NULL NULL NULL NULL double +NULL mysql column_stat nulls_ratio decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stat avg_length decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stat avg_frequency decimal NULL NULL NULL NULL decimal(12,4) 3.0000 mysql db Host char 60 180 utf8 utf8_bin char(60) 3.0000 mysql db Db char 64 192 utf8 utf8_bin char(64) 3.0000 mysql db User char 16 48 utf8 utf8_bin char(16) @@ -420,7 +420,7 @@ NULL mysql help_topic help_category_id smallint NULL NULL NULL NULL smallint(5) 3.0000 mysql index_stat table_name varchar 64 192 utf8 utf8_bin varchar(64) 3.0000 mysql index_stat index_name varchar 64 192 utf8 utf8_bin varchar(64) NULL mysql index_stat prefix_arity int NULL NULL NULL NULL int(11) unsigned -NULL mysql index_stat avg_frequency double NULL NULL NULL NULL double +NULL mysql index_stat avg_frequency decimal NULL NULL NULL NULL decimal(12,4) NULL mysql ndb_binlog_index Position bigint NULL NULL NULL NULL bigint(20) unsigned 1.0000 mysql ndb_binlog_index File varchar 255 255 latin1 latin1_swedish_ci varchar(255) NULL mysql ndb_binlog_index epoch bigint NULL NULL NULL NULL bigint(20) unsigned diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index e4676c7b340..600c7eff105 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -6,22 +6,6 @@ drop table if exists t1,t2; set @save_use_stat_tables=@@use_stat_tables; -CREATE VIEW table_stat AS -SELECT * FROM mysql.table_stat; - -CREATE VIEW column_stat AS - SELECT db_name, table_name, column_name, - min_value, max_value, - CAST(nulls_ratio AS decimal(12,4)) AS 'nulls_ratio', - CAST(avg_length AS decimal(12,4)) AS 'avg_length', - CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' - FROM mysql.column_stat; - -CREATE VIEW index_stat AS - SELECT db_name, table_name, index_name, prefix_arity, - CAST(avg_frequency AS decimal(12,4)) AS 'avg_frequency' - FROM mysql.index_stat; - DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; @@ -85,13 +69,13 @@ INSERT INTO t1 VALUES ANALYZE TABLE t1; -SELECT * FROM table_stat; -SELECT * FROM column_stat; -SELECT * FROM index_stat; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; SELECT COUNT(*) FROM t1; -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='a'; SELECT MIN(t1.a), MAX(t1.a), (SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / @@ -100,7 +84,7 @@ SELECT MIN(t1.a), MAX(t1.a), (SELECT COUNT(DISTINCT t1.a) FROM t1) AS "AVG_FREQUENCY(t1.a)" FROM t1; -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='b'; SELECT MIN(t1.b), MAX(t1.b), (SELECT COUNT(*) FROM t1 WHERE t1.b IS NULL) / @@ -109,7 +93,7 @@ SELECT MIN(t1.b), MAX(t1.b), (SELECT COUNT(DISTINCT t1.b) FROM t1) AS "AVG_FREQUENCY(t1.b)" FROM t1; -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='c'; SELECT MIN(t1.c), MAX(t1.c), (SELECT COUNT(*) FROM t1 WHERE t1.c IS NULL) / @@ -118,7 +102,7 @@ SELECT MIN(t1.c), MAX(t1.c), (SELECT COUNT(DISTINCT t1.c) FROM t1) AS "AVG_FREQUENCY(t1.c)" FROM t1; -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='d'; SELECT MIN(t1.d), MAX(t1.d), (SELECT COUNT(*) FROM t1 WHERE t1.d IS NULL) / @@ -127,7 +111,7 @@ SELECT MIN(t1.d), MAX(t1.d), (SELECT COUNT(DISTINCT t1.d) FROM t1) AS "AVG_FREQUENCY(t1.d)" FROM t1; -SELECT * FROM column_stat +SELECT * FROM mysql.column_stat WHERE db_name='test' AND table_name='t1' AND column_name='e'; SELECT MIN(t1.e), MAX(t1.e), (SELECT COUNT(*) FROM t1 WHERE t1.e IS NULL) / @@ -136,7 +120,7 @@ SELECT MIN(t1.e), MAX(t1.e), (SELECT COUNT(DISTINCT t1.e) FROM t1) AS "AVG_FREQUENCY(t1.e)" FROM t1; -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx1'; SELECT (SELECT COUNT(*) FROM t1 WHERE t1.b IS NOT NULL) / @@ -147,7 +131,7 @@ SELECT WHERE t1.b IS NOT NULL AND t1.e IS NOT NULL) AS 'ARITY 2'; -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx2'; SELECT (SELECT COUNT(*) FROM t1 WHERE t1.c IS NOT NULL) / @@ -158,14 +142,14 @@ SELECT WHERE t1.c IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 2'; -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx3'; SELECT (SELECT COUNT(*) FROM t1 WHERE t1.d IS NOT NULL) / (SELECT COUNT(DISTINCT t1.d) FROM t1 WHERE t1.d IS NOT NULL) AS 'ARITY 1'; -SELECT * FROM index_stat +SELECT * FROM mysql.index_stat WHERE db_name='test' AND table_name='t1' AND index_name='idx4'; SELECT (SELECT COUNT(*) FROM t1 WHERE t1.e IS NOT NULL) / @@ -186,14 +170,14 @@ DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(); -SELECT * FROM table_stat; -SELECT * FROM column_stat; -SELECT * FROM index_stat; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); -SELECT * FROM table_stat; -SELECT * FROM column_stat; -SELECT * FROM index_stat; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; @@ -201,9 +185,9 @@ DELETE FROM mysql.index_stat; ANALYZE TABLE t1 PERSISTENT FOR COLUMNS ALL INDEXES ALL; -SELECT * FROM table_stat; -SELECT * FROM column_stat; -SELECT * FROM index_stat; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; CREATE TABLE t2 LIKE t1; @@ -212,9 +196,9 @@ INSERT INTO t2 SELECT * FROM t1; ANALYZE TABLE t2; -SELECT * FROM table_stat; -SELECT * FROM column_stat ORDER BY column_name; -SELECT * FROM index_stat ORDER BY index_name, prefix_arity, table_name; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat ORDER BY column_name; +SELECT * FROM mysql.index_stat ORDER BY index_name, prefix_arity, table_name; DELETE FROM mysql.table_stat; @@ -231,8 +215,8 @@ ALTER TABLE t1 ANALYZE TABLE t1; -SELECT * FROM column_stat; -SELECT * FROM index_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; DROP TABLE t1,t2; @@ -265,13 +249,13 @@ ANALYZE TABLE Country, City, CountryLanguage; --enable_result_log SELECT UPPER(db_name), UPPER(table_name), cardinality - FROM test.table_stat; + FROM mysql.table_stat; SELECT UPPER(db_name), UPPER(table_name), column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency - FROM test.column_stat; + FROM mysql.column_stat; SELECT UPPER(db_name), UPPER(table_name), index_name, prefix_arity, avg_frequency - FROM test.index_stat; + FROM mysql.index_stat; use test; @@ -302,13 +286,13 @@ ANALYZE TABLE Country, City, CountryLanguage; --enable_result_log SELECT UPPER(db_name), UPPER(table_name), cardinality - FROM test.table_stat; + FROM mysql.table_stat; SELECT UPPER(db_name), UPPER(table_name), column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency - FROM test.column_stat; + FROM mysql.column_stat; SELECT UPPER(db_name), UPPER(table_name), index_name, prefix_arity, avg_frequency - FROM test.index_stat; + FROM mysql.index_stat; use test; @@ -319,10 +303,6 @@ DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; -DROP VIEW test.table_stat; -DROP VIEW test.column_stat; -DROP VIEW test.index_stat; - set use_stat_tables=@save_use_stat_tables; \ No newline at end of file diff --git a/scripts/mysql_system_tables.sql b/scripts/mysql_system_tables.sql index eaf4fda4026..e7d16c5b798 100644 --- a/scripts/mysql_system_tables.sql +++ b/scripts/mysql_system_tables.sql @@ -485,6 +485,6 @@ set @had_proxies_priv_table= @@warning_count != 0; CREATE TABLE IF NOT EXISTS table_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, cardinality bigint(21) unsigned DEFAULT NULL, PRIMARY KEY (db_name,table_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Tables'; -CREATE TABLE IF NOT EXISTS column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio double DEFAULT NULL, avg_length double DEFAULT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; +CREATE TABLE IF NOT EXISTS column_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, column_name varchar(64) NOT NULL, min_value varchar(255) DEFAULT NULL, max_value varchar(255) DEFAULT NULL, nulls_ratio decimal(12,4) DEFAULT NULL, avg_length decimal(12,4) DEFAULT NULL, avg_frequency decimal(12,4) DEFAULT NULL, PRIMARY KEY (db_name,table_name,column_name) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Columns'; -CREATE TABLE IF NOT EXISTS index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency double DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; +CREATE TABLE IF NOT EXISTS index_stat (db_name varchar(64) NOT NULL, table_name varchar(64) NOT NULL, index_name varchar(64) NOT NULL, prefix_arity int(11) unsigned NOT NULL, avg_frequency decimal(12,4) DEFAULT NULL, PRIMARY KEY (db_name,table_name,index_name,prefix_arity) ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_bin comment='Statistics on Indexes'; diff --git a/sql/field.h b/sql/field.h index 16ff02c6789..5df2f57fee4 100644 --- a/sql/field.h +++ b/sql/field.h @@ -219,6 +219,10 @@ public: /* Statistical data on a column */ class Column_statistics { + private: + static const uint Scale_factor_nulls_ratio= 100000; + static const uint Scale_factor_avg_length= 100000; + static const uint Scale_factor_avg_frequency= 100000; public: /* Bitmap indicating what statistical characteristics @@ -230,23 +234,54 @@ public: Field *min_value; /* Maximum value for the column */ Field *max_value; + private: /* - The ratio Z/N, where N is the total number of rows, + The ratio Z/N multiplied by the scale factor Scale_factor_nulls_ratio, + where N is the total number of rows, Z is the number of nulls in the column */ - double nulls_ratio; + ulong nulls_ratio; /* Average number of bytes occupied by the representation of a - value of the column in memory buffers such as join buffer. - CHAR values are stripped of trailing spaces. + value of the column in memory buffers such as join buffer + multiplied by the scale factor Scale_factor_avg_length + CHAR values are stripped of trailing spaces Flexible values are stripped of their length prefixes. */ - double avg_length; + ulong avg_length; /* - The ratio N/D, where N is the number of rows with null value + The ratio N/D multiplied by the scale factor Scale_factor_avg_frequency, + where N is the number of rows with null value in the column, D the number of distinct values among them */ - double avg_frequency; + ulong avg_frequency; + + public: + double get_nulls_ratio() + { + return (double) nulls_ratio / Scale_factor_nulls_ratio; + } + double get_avg_length() + { + return (double) avg_length / Scale_factor_avg_length; + } + double get_avg_frequency() + { + return (double) avg_frequency / Scale_factor_avg_frequency; + } + + void set_nulls_ratio (double val) + { + nulls_ratio= (ulong) (val * Scale_factor_nulls_ratio); + } + void set_avg_length (double val) + { + avg_length= (ulong) (val * Scale_factor_avg_length); + } + void set_avg_frequency (double val) + { + avg_frequency= (ulong) (val * Scale_factor_avg_frequency); + } }; /* diff --git a/sql/sql_select.cc b/sql/sql_select.cc index cf0063b80d4..49a35ccf18b 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -14595,8 +14595,8 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->ext_key_parts= keyinfo->key_parts; keyinfo->key_length=0; keyinfo->rec_per_key=NULL; - keyinfo->read_stat.avg_frequency= NULL; - keyinfo->write_stat.avg_frequency= NULL; + keyinfo->read_stat.init_avg_frequency(NULL); + keyinfo->write_stat.init_avg_frequency(NULL); keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->name= (char*) "group_key"; @@ -14713,7 +14713,7 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->rec_per_key=0; - keyinfo->read_stat.avg_frequency= NULL; + keyinfo->read_stat.init_avg_frequency(NULL); /* Create an extra field to hold NULL bits so that unique indexes on diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index c2505cdc6ef..de5f2976053 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -600,13 +600,13 @@ public: } break; case COLUMN_STAT_NULLS_RATIO: - stat_field->store(table_field->write_stat.nulls_ratio); + stat_field->store(table_field->write_stat.get_nulls_ratio()); break; case COLUMN_STAT_AVG_LENGTH: - stat_field->store(table_field->write_stat.avg_length); + stat_field->store(table_field->write_stat.get_avg_length()); break; case COLUMN_STAT_AVG_FREQUENCY: - stat_field->store(table_field->write_stat.avg_frequency); + stat_field->store(table_field->write_stat.get_avg_frequency()); break; } } @@ -665,13 +665,13 @@ public: &my_charset_utf8_bin); break; case COLUMN_STAT_NULLS_RATIO: - table_field->read_stat.nulls_ratio= stat_field->val_real(); + table_field->read_stat.set_nulls_ratio(stat_field->val_real()); break; case COLUMN_STAT_AVG_LENGTH: - table_field->read_stat.avg_length= stat_field->val_real(); + table_field->read_stat.set_avg_length(stat_field->val_real()); break; case COLUMN_STAT_AVG_FREQUENCY: - table_field->read_stat.avg_frequency= stat_field->val_real(); + table_field->read_stat.set_avg_frequency(stat_field->val_real()); break; } } @@ -766,7 +766,7 @@ public: { Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; double avg_frequency= - table_key_info->write_stat.avg_frequency[prefix_arity-1]; + table_key_info->write_stat.get_avg_frequency(prefix_arity-1); if (avg_frequency == 0) stat_field->set_null(); else @@ -798,9 +798,9 @@ public: { Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; if (!stat_field->is_null()) - avg_frequency= stat_field->val_real(); + avg_frequency= stat_field->val_real(); } - table_key_info->read_stat.avg_frequency[prefix_arity-1]= avg_frequency; + table_key_info->read_stat.set_avg_frequency(prefix_arity-1, avg_frequency); } }; @@ -1065,9 +1065,9 @@ public: { if (i < prefixes) { - index_info->write_stat.avg_frequency[i]= - state->prefix_count == 0 ? 0 : - (double) state->entry_count / state->prefix_count; + double val= state->prefix_count == 0 ? + 0 : (double) state->entry_count / state->prefix_count; + index_info->write_stat.set_avg_frequency(i, val); } } } @@ -1354,17 +1354,19 @@ int collect_statistics_for_table(THD *thd, TABLE *table) for (field_ptr= table->field; *field_ptr; field_ptr++) { + double val; table_field= *field_ptr; if (!bitmap_is_set(table->read_set, table_field->field_index)) continue; - table_field->write_stat.nulls_ratio= (double) table_field->nulls/rows; - table_field->write_stat.avg_length= - (double) table_field->column_total_length / (rows-table_field->nulls); + val= (double) table_field->nulls / rows; + table_field->write_stat.set_nulls_ratio(val); + val= (double) table_field->column_total_length / (rows-table_field->nulls); + table_field->write_stat.set_avg_length(val); if (table_field->count_distinct) { - table_field->write_stat.avg_frequency= - (double) (rows-table_field->nulls) / - table_field->count_distinct->get_value(); + val= (double) (rows-table_field->nulls) / + table_field->count_distinct->get_value(); + table_field->write_stat.set_avg_frequency(val); set_not_null_for_write_column_stat_value(table_field, COLUMN_STAT_AVG_FREQUENCY); delete table_field->count_distinct; @@ -1585,38 +1587,37 @@ int read_statistics_for_table(THD *thd, TABLE *table) key_part_map ext_key_part_map= key_info->ext_key_part_map; if (key_info->key_parts != key_info->ext_key_parts && - key_info->read_stat.avg_frequency[key_info->key_parts] == 0) + key_info->read_stat.get_avg_frequency(key_info->key_parts) == 0) { - double *ptr; - double *ptr_end; KEY *pk_key_info= table->key_info + table->s->primary_key; uint k= key_info->key_parts; uint pk_parts= pk_key_info->key_parts; ha_rows n_rows= table->read_stat.cardinality; - double k_dist= n_rows / key_info->read_stat.avg_frequency[k-1]; - double *k_avg_freq_ptr= key_info->read_stat.avg_frequency + k; + double k_dist= n_rows / key_info->read_stat.get_avg_frequency(k-1); uint m= 0; for (uint j= 0; j < pk_parts; j++) { if (!(ext_key_part_map & 1 << j)) { - for (ptr= k_avg_freq_ptr, ptr_end= ptr + m; ptr < ptr_end; ptr++) + for (uint l= k; l < k + m; l++) { - double avg_frequency= pk_key_info->read_stat.avg_frequency[j-1]; + double avg_frequency= pk_key_info->read_stat.get_avg_frequency(j-1); set_if_smaller(avg_frequency, 1); - (*ptr)*= pk_key_info->read_stat.avg_frequency[j]/avg_frequency; + double val= pk_key_info->read_stat.get_avg_frequency(j) / + avg_frequency; + key_info->read_stat.set_avg_frequency (l, val); } } else { - key_info->read_stat.avg_frequency[k + m]= - pk_key_info->read_stat.avg_frequency[j]; - m++; + double avg_frequency= pk_key_info->read_stat.get_avg_frequency(j); + key_info->read_stat.set_avg_frequency(k + m, avg_frequency); + m++; } } - for (ptr= k_avg_freq_ptr, ptr_end= ptr + m; ptr < ptr_end; ptr++) + for (uint l= k; l < k + m; l++) { - double avg_frequency= *ptr; + double avg_frequency= key_info->read_stat.get_avg_frequency(l); if (avg_frequency == 0 || table->read_stat.cardinality_is_null) avg_frequency= 1; @@ -1625,7 +1626,7 @@ int read_statistics_for_table(THD *thd, TABLE *table) avg_frequency/= k_dist; set_if_bigger(avg_frequency, 1); } - *ptr= avg_frequency; + key_info->read_stat.set_avg_frequency(l, avg_frequency); } } } @@ -1662,7 +1663,8 @@ void set_statistics_for_table(THD *thd, TABLE *table) key_info < key_info_end; key_info++) { key_info->is_statistics_from_stat_tables= - (use_stat_table_mode > 1 && key_info->read_stat.avg_frequency && - key_info->read_stat.avg_frequency[0] > 0.5); + (use_stat_table_mode > 1 && + key_info->read_stat.avg_frequency_is_set() && + key_info->read_stat.get_avg_frequency(0) > 0.5); } } diff --git a/sql/structs.h b/sql/structs.h index 9949a72964b..4a70820586d 100644 --- a/sql/structs.h +++ b/sql/structs.h @@ -124,14 +124,28 @@ typedef struct st_key { /* Statistical data on an index prefixes */ class Index_statistics { - public: + private: + static const uint Scale_factor_avg_frequency= 100000; /* - The k-th element of this array contains the ratio N/D, + The k-th element of this array contains the ratio N/D + multiplied by the scale factor Scale_factor_avg_frequency, where N is the number of index entries without nulls in the first k components, and D is the number of distinct k-component prefixes among them */ - double *avg_frequency; + ulong *avg_frequency; + + public: + void init_avg_frequency(ulong *ptr) { avg_frequency= ptr; } + bool avg_frequency_is_set() { return avg_frequency != NULL; } + double get_avg_frequency(uint i) + { + return (double) avg_frequency[i] / Scale_factor_avg_frequency; + } + void set_avg_frequency(uint i, double val) + { + avg_frequency[i]= (ulong) (val * Scale_factor_avg_frequency); + } }; /* @@ -159,8 +173,7 @@ typedef struct st_key { if (rec_per_key == 0) return 0; return (is_statistics_from_stat_tables ? - (ulong) (100 * read_stat.avg_frequency[i]) / (double) 100 : - (double) rec_per_key[i]); + read_stat.get_avg_frequency(i) : (double) rec_per_key[i]); } } KEY; diff --git a/sql/table.cc b/sql/table.cc index de5c11ed92d..48f40a05c33 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -762,8 +762,8 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, ulong pos, record_offset; ulong *rec_per_key= NULL; ulong rec_buff_length; - double *read_avg_frequency= NULL; - double *write_avg_frequency= NULL; + ulong *read_avg_frequency= NULL; + ulong *write_avg_frequency= NULL; handler *handler_file= 0; KEY *keyinfo; KEY_PART_INFO *key_part= NULL; @@ -946,13 +946,13 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, if (!(rec_per_key= (ulong*) alloc_root(&share->mem_root, sizeof(ulong) * ext_key_parts))) goto err; - if (!(read_avg_frequency= (double*) alloc_root(&share->mem_root, - sizeof(double) * - ext_key_parts))) + if (!(read_avg_frequency= (ulong*) alloc_root(&share->mem_root, + sizeof(double) * + ext_key_parts))) goto err; - if (!(write_avg_frequency= (double*) alloc_root(&share->mem_root, - sizeof(double) * - ext_key_parts))) + if (!(write_avg_frequency= (ulong*) alloc_root(&share->mem_root, + sizeof(double) * + ext_key_parts))) goto err; first_key_part= key_part; first_key_parts= first_keyinfo.key_parts; @@ -966,8 +966,8 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, keyinfo->key_part= key_part; keyinfo->rec_per_key= rec_per_key; - keyinfo->read_stat.avg_frequency= read_avg_frequency; - keyinfo->write_stat.avg_frequency= write_avg_frequency; + keyinfo->read_stat.init_avg_frequency(read_avg_frequency); + keyinfo->write_stat.init_avg_frequency(write_avg_frequency); for (j=keyinfo->key_parts ; j-- ; key_part++) { *rec_per_key++=0; @@ -5957,7 +5957,7 @@ bool TABLE::add_tmp_key(uint key, uint key_parts, if (!keyinfo->rec_per_key) return TRUE; bzero(keyinfo->rec_per_key, sizeof(ulong)*key_parts); - keyinfo->read_stat.avg_frequency= NULL; + keyinfo->read_stat.init_avg_frequency(NULL); for (i= 0; i < key_parts; i++) { From 47fae7f08fd0437cd555bbd6b2533a4117340c8d Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 10 Jul 2012 16:34:39 -0700 Subject: [PATCH 17/35] Added procedures to delete records by keys from statistical tables. Now when a table is dropped the statistics on the table is removed from the statistical tables. If the table is altered in such a way that a column is dropped or the type of the column is changed then statistics on the column is removed from the table column_stat. It also triggers removal of the statistics on the indexes who use this column as its component. Added procedures that changes the names of the tables or columns in the statistical tables for. These procedures are used when tables/columns are renamed. Also partly re-factored the code that introduced the persistent statistical tables. Added test cases into statistics.test to cover the new code. --- mysql-test/r/statistics.result | 705 ++++++++++- mysql-test/r/status_user.result | 4 +- .../suite/perfschema/r/myisam_file_io.result | 1 + .../suite/perfschema/t/myisam_file_io.test | 1 + mysql-test/t/statistics.test | 185 ++- sql/sql_base.cc | 3 +- sql/sql_base.h | 7 + sql/sql_db.cc | 11 + sql/sql_rename.cc | 6 + sql/sql_statistics.cc | 1051 ++++++++++++++--- sql/sql_table.cc | 64 +- 11 files changed, 1887 insertions(+), 151 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 99d3c04312b..a4e60e266d0 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -12,10 +12,10 @@ d date, e double, f bit(3), INDEX idx1 (b, e), -INDEX idx2(c, d), +INDEX idx2 (c, d), INDEX idx3 (d), INDEX idx4 (e, b, d) -); +) ENGINE= MYISAM; INSERT INTO t1 VALUES (0, NULL, NULL, NULL, NULL, NULL), (7, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'dddddddd', '1990-05-15', 0.1, b'100'), @@ -206,6 +206,662 @@ WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 3'; ARITY 1 ARITY 2 ARITY 3 6.2000 1.6875 1.1304 +CREATE TABLE t3 ( +a int NOT NULL PRIMARY KEY, +b varchar(32), +c char(16), +INDEX idx (c) +) ENGINE=MYISAM; +INSERT INTO t3 VALUES +(0, NULL, NULL), +(7, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'dddddddd'), +(17, 'vvvvvvvvvvvvv', 'aaaa'), +(1, 'vvvvvvvvvvvvv', NULL), +(12, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd'), +(23, 'vvvvvvvvvvvvv', 'dddddddd'), +(8, 'vvvvvvvvvvvvv', 'aaaa'), +(22, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'aaaa'), +(31, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'aaaa'), +(10, NULL, 'aaaa'), +(5, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd'), +(15, 'vvvvvvvvvvvvv', 'ccccccccc'), +(30, NULL, 'bbbbbb'), +(38, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb'), +(18, 'zzzzzzzzzzzzzzzzzz', 'ccccccccc'), +(9, 'yyy', 'bbbbbb'), +(29, 'vvvvvvvvvvvvv', 'dddddddd'); +ANALYZE TABLE t3; +Table Op Msg_type Msg_text +test.t3 analyze status OK +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test t1 40 +test t3 17 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +test t3 a 0 38 0.0000 4.0000 1.0000 +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +test t3 PRIMARY 1 1.0000 +test t3 idx 1 3.7500 +ALTER TABLE t1 RENAME TO s1; +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test s1 40 +test t3 17 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test s1 a 0 49 0.0000 4.0000 1.0000 +test s1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 +test s1 f 1 5 0.2000 1.0000 6.4000 +test t3 a 0 38 0.0000 4.0000 1.0000 +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test s1 PRIMARY 1 1.0000 +test s1 idx1 1 6.4000 +test s1 idx1 2 1.6875 +test s1 idx2 1 7.0000 +test s1 idx2 2 2.3846 +test s1 idx3 1 8.5000 +test s1 idx4 1 6.2000 +test s1 idx4 2 1.6875 +test s1 idx4 3 1.1304 +test t3 PRIMARY 1 1.0000 +test t3 idx 1 3.7500 +RENAME TABLE s1 TO t1; +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test t1 40 +test t3 17 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +test t3 a 0 38 0.0000 4.0000 1.0000 +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +test t3 PRIMARY 1 1.0000 +test t3 idx 1 3.7500 +DROP TABLE t3; +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +CREATE TEMPORARY TABLE t0 ( +a int NOT NULL PRIMARY KEY, +b varchar(32) +); +INSERT INTO t0 SELECT a,b FROM t1; +ALTER TABLE t1 CHANGE COLUMN b x varchar(32), +CHANGE COLUMN e y double; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `x` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `y` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`x`,`y`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`y`,`x`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 y 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +ALTER TABLE t1 CHANGE COLUMN x b varchar(32), +CHANGE COLUMN y e double; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `b` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +ALTER TABLE t1 RENAME TO s1, CHANGE COLUMN b x varchar(32); +SHOW CREATE TABLE s1; +Table Create Table +s1 CREATE TABLE `s1` ( + `a` int(11) NOT NULL, + `x` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`x`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`x`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test s1 40 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test s1 a 0 49 0.0000 4.0000 1.0000 +test s1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 +test s1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test s1 PRIMARY 1 1.0000 +test s1 idx1 1 6.4000 +test s1 idx1 2 1.6875 +test s1 idx2 1 7.0000 +test s1 idx2 2 2.3846 +test s1 idx3 1 8.5000 +test s1 idx4 1 6.2000 +test s1 idx4 2 1.6875 +test s1 idx4 3 1.1304 +ALTER TABLE s1 RENAME TO t1, CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `b` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +test t1 40 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +ALTER TABLE t1 CHANGE COLUMN b x varchar(30); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `x` varchar(30) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`x`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`x`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx1 1 6.4000 +test t1 idx1 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +ALTER TABLE t1 CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `b` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx4); +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx4 3 1.1304 +test t1 idx4 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx1 2 1.6875 +test t1 idx1 1 6.4000 +SELECT * INTO OUTFILE 'MYSQLTEST_VARDIR/tmp/save_column_stat' + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' + FROM mysql.column_stat WHERE column_name='b'; +SELECT * INTO OUTFILE 'MYSQLTEST_VARDIR/tmp/save_index_stat' + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' + FROM mysql.index_stat WHERE index_name IN ('idx1', 'idx4'); +ALTER TABLE t1 CHANGE COLUMN b x varchar(30); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `x` varchar(30) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`x`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`x`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx4 3 1.1304 +test t1 idx4 2 1.6875 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 1 6.2000 +test t1 idx1 2 1.6875 +test t1 idx1 1 6.4000 +ALTER TABLE t1 CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `b` varchar(32) DEFAULT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +LOAD DATA INFILE 'MYSQLTEST_VARDIR/tmp/save_column_stat' + INTO TABLE mysql.column_stat +FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; +LOAD DATA INFILE 'MYSQLTEST_VARDIR/tmp/save_index_stat' + INTO TABLE mysql.index_stat +FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx4 3 1.1304 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +test t1 idx4 2 1.6875 +test t1 idx4 1 6.2000 +test t1 idx1 2 1.6875 +test t1 idx1 1 6.4000 +ALTER TABLE t1 DROP COLUMN b; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`e`), + KEY `idx2` (`c`,`d`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx3 1 8.5000 +DROP INDEX idx2 ON t1; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx1` (`e`), + KEY `idx3` (`d`), + KEY `idx4` (`e`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 +DROP INDEX idx1 ON t1; +DROP INDEX idx4 ON t1; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx3` (`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +ALTER TABLE t1 ADD COLUMN b varchar(32); +CREATE INDEX idx1 ON t1(b, e); +CREATE INDEX idx2 ON t1(c, d); +CREATE INDEX idx4 ON t1(e, b, d); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + `b` varchar(32) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx3` (`d`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b NULL NULL 1.0000 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx1 2 NULL +test t1 idx1 1 NULL +test t1 idx3 1 8.5000 +test t1 idx2 2 2.3846 +test t1 idx4 1 6.2000 +test t1 idx4 2 NULL +test t1 idx4 3 NULL +UPDATE t1 SET b=(SELECT b FROM t0 WHERE t0.a= t1.a); +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx2 1 7.0000 +test t1 idx1 2 1.6875 +test t1 idx1 1 6.4000 +test t1 idx3 1 8.5000 +test t1 idx2 2 2.3846 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +ALTER TABLE t1 DROP COLUMN b, +DROP INDEX idx1, DROP INDEX idx2, DROP INDEX idx4; +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx3` (`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 +ALTER TABLE t1 ADD COLUMN b varchar(32); +ALTER TABLE t1 +ADD INDEX idx1 (b, e), ADD INDEX idx2 (c, d), ADD INDEX idx4 (e, b, d); +UPDATE t1 SET b=(SELECT b FROM t0 WHERE t0.a= t1.a); +SHOW CREATE TABLE t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) NOT NULL, + `c` char(16) DEFAULT NULL, + `d` date DEFAULT NULL, + `e` double DEFAULT NULL, + `f` bit(3) DEFAULT NULL, + `b` varchar(32) DEFAULT NULL, + PRIMARY KEY (`a`), + KEY `idx3` (`d`), + KEY `idx1` (`b`,`e`), + KEY `idx2` (`c`,`d`), + KEY `idx4` (`e`,`b`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +Table Op Msg_type Msg_text +test.t1 analyze status OK +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +test t1 a 0 49 0.0000 4.0000 1.0000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 f 1 5 0.2000 1.0000 6.4000 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 PRIMARY 1 1.0000 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx3 1 8.5000 +test t1 idx2 2 2.3846 +test t1 idx2 1 7.0000 +test t1 idx1 2 1.6875 +test t1 idx1 1 6.4000 +test t1 idx4 3 1.1304 DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; @@ -227,9 +883,9 @@ db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 idx2 1 7.0000 @@ -249,19 +905,19 @@ test t1 40 SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 test t1 idx1 1 6.4000 test t1 idx1 2 1.6875 test t1 idx2 1 7.0000 test t1 idx2 2 2.3846 -test t1 idx3 1 8.5000 test t1 idx4 1 6.2000 test t1 idx4 2 1.6875 test t1 idx4 3 1.1304 @@ -325,17 +981,17 @@ test.t1 analyze status OK SELECT * FROM mysql.column_stat; db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency test t1 a 0 49 0.0000 4.0000 1.0000 -test t1 b NULL NULL 0.2000 17.1250 NULL test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 test t1 e 0.01 0.112 0.2250 8.0000 6.2000 test t1 f 1 5 0.2000 1.0000 6.4000 +test t1 b NULL NULL 0.2000 17.1250 NULL SELECT * FROM mysql.index_stat; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 +test t1 idx3 1 8.5000 test t1 idx2 1 7.0000 test t1 idx2 2 2.3846 -test t1 idx3 1 8.5000 test t1 idx1 1 NULL test t1 idx1 2 NULL test t1 idx4 1 6.2000 @@ -503,7 +1159,42 @@ WORLD_INNODB COUNTRYLANGUAGE PRIMARY 2 1.0000 WORLD_INNODB COUNTRYLANGUAGE Percentage 1 2.7640 use test; DROP DATABASE world; +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +world_innodb Country 239 +world_innodb City 4079 +world_innodb CountryLanguage 984 +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +world_innodb Country Code ABW ZWE 0.0000 3.0000 1.0000 +world_innodb Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +world_innodb Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +world_innodb Country Population 0 1277558000 0.0000 4.0000 1.0575 +world_innodb Country Capital 1 4074 0.0293 4.0000 1.0000 +world_innodb City ID 1 4079 0.0000 4.0000 1.0000 +world_innodb City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +world_innodb City Country ABW ZWE 0.0000 3.0000 17.5819 +world_innodb City Population 42 10500000 0.0000 4.0000 1.0467 +world_innodb CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 +world_innodb CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +world_innodb CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +world_innodb Country PRIMARY 1 1.0000 +world_innodb Country Name 1 1.0000 +world_innodb City PRIMARY 1 1.0000 +world_innodb City Population 1 1.0467 +world_innodb City Country 1 17.5819 +world_innodb CountryLanguage PRIMARY 1 4.2232 +world_innodb CountryLanguage PRIMARY 2 1.0000 +world_innodb CountryLanguage Percentage 1 2.7640 DROP DATABASE world_innodb; +SELECT * FROM mysql.table_stat; +db_name table_name cardinality +SELECT * FROM mysql.column_stat; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; diff --git a/mysql-test/r/status_user.result b/mysql-test/r/status_user.result index f43e217b8a5..040b2d85a51 100644 --- a/mysql-test/r/status_user.result +++ b/mysql-test/r/status_user.result @@ -107,7 +107,7 @@ Handler_mrr_key_refills 0 Handler_mrr_rowid_refills 0 Handler_prepare 18 Handler_read_first 0 -Handler_read_key 3 +Handler_read_key 9 Handler_read_last 0 Handler_read_next 0 Handler_read_prev 0 @@ -123,7 +123,7 @@ Handler_update 5 Handler_write 7 select variable_value - @global_read_key as "handler_read_key" from information_schema.global_status where variable_name="handler_read_key"; handler_read_key -3 +9 set @@global.userstat=0; select * from information_schema.index_statistics; TABLE_SCHEMA TABLE_NAME INDEX_NAME ROWS_READ diff --git a/mysql-test/suite/perfschema/r/myisam_file_io.result b/mysql-test/suite/perfschema/r/myisam_file_io.result index 5cdcf6ac789..eb8b0d6f9f5 100644 --- a/mysql-test/suite/perfschema/r/myisam_file_io.result +++ b/mysql-test/suite/perfschema/r/myisam_file_io.result @@ -17,6 +17,7 @@ substring(object_name, locate("no_index_tab", object_name)) as short_name from performance_schema.events_waits_history_long where operation not like "tell" and event_name like "wait/io/file/myisam/%" + having short_name <> "" order by thread_id, event_id; event_name short_source operation number_of_bytes short_name wait/io/file/myisam/kfile mi_create.c: create NULL no_index_tab.MYI diff --git a/mysql-test/suite/perfschema/t/myisam_file_io.test b/mysql-test/suite/perfschema/t/myisam_file_io.test index 5888c29fe22..d93edd7d3b6 100644 --- a/mysql-test/suite/perfschema/t/myisam_file_io.test +++ b/mysql-test/suite/perfschema/t/myisam_file_io.test @@ -46,6 +46,7 @@ select event_name, from performance_schema.events_waits_history_long where operation not like "tell" and event_name like "wait/io/file/myisam/%" + having short_name <> "" order by thread_id, event_id; # In case of failures, this will tell if file io are lost. diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 600c7eff105..0427c82349c 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -20,10 +20,10 @@ CREATE TABLE t1 ( e double, f bit(3), INDEX idx1 (b, e), - INDEX idx2(c, d), + INDEX idx2 (c, d), INDEX idx3 (d), INDEX idx4 (e, b, d) -); +) ENGINE= MYISAM; INSERT INTO t1 VALUES (0, NULL, NULL, NULL, NULL, NULL), @@ -165,6 +165,180 @@ SELECT WHERE t1.e IS NOT NULL AND t1.b IS NOT NULL AND t1.d IS NOT NULL) AS 'ARITY 3'; +CREATE TABLE t3 ( + a int NOT NULL PRIMARY KEY, + b varchar(32), + c char(16), + INDEX idx (c) +) ENGINE=MYISAM; + +INSERT INTO t3 VALUES + (0, NULL, NULL), + (7, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'dddddddd'), + (17, 'vvvvvvvvvvvvv', 'aaaa'), + (1, 'vvvvvvvvvvvvv', NULL), + (12, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd'), + (23, 'vvvvvvvvvvvvv', 'dddddddd'), + (8, 'vvvvvvvvvvvvv', 'aaaa'), + (22, 'xxxxxxxxxxxxxxxxxxxxxxxxxx', 'aaaa'), + (31, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'aaaa'), + (10, NULL, 'aaaa'), + (5, 'wwwwwwwwwwwwwwwwwwwwwwwwwwww', 'dddddddd'), + (15, 'vvvvvvvvvvvvv', 'ccccccccc'), + (30, NULL, 'bbbbbb'), + (38, 'zzzzzzzzzzzzzzzzzz', 'bbbbbb'), + (18, 'zzzzzzzzzzzzzzzzzz', 'ccccccccc'), + (9, 'yyy', 'bbbbbb'), + (29, 'vvvvvvvvvvvvv', 'dddddddd'); + +ANALYZE TABLE t3; + +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 RENAME TO s1; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +RENAME TABLE s1 TO t1; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +DROP TABLE t3; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + + +CREATE TEMPORARY TABLE t0 ( + a int NOT NULL PRIMARY KEY, + b varchar(32) +); +INSERT INTO t0 SELECT a,b FROM t1; + +ALTER TABLE t1 CHANGE COLUMN b x varchar(32), + CHANGE COLUMN e y double; +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; + +ALTER TABLE t1 CHANGE COLUMN x b varchar(32), + CHANGE COLUMN y e double; +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; + +ALTER TABLE t1 RENAME TO s1, CHANGE COLUMN b x varchar(32); +SHOW CREATE TABLE s1; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE s1 RENAME TO t1, CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 CHANGE COLUMN b x varchar(30); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx4); +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR +eval +SELECT * INTO OUTFILE '$MYSQLTEST_VARDIR/tmp/save_column_stat' + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' + FROM mysql.column_stat WHERE column_name='b'; +--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR +eval +SELECT * INTO OUTFILE '$MYSQLTEST_VARDIR/tmp/save_index_stat' + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' + FROM mysql.index_stat WHERE index_name IN ('idx1', 'idx4'); + +ALTER TABLE t1 CHANGE COLUMN b x varchar(30); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 CHANGE COLUMN x b varchar(32); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR +eval +LOAD DATA INFILE '$MYSQLTEST_VARDIR/tmp/save_column_stat' + INTO TABLE mysql.column_stat + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; +--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR +eval +LOAD DATA INFILE '$MYSQLTEST_VARDIR/tmp/save_index_stat' + INTO TABLE mysql.index_stat + FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; +remove_file $MYSQLTEST_VARDIR/tmp/save_column_stat; +remove_file $MYSQLTEST_VARDIR/tmp/save_index_stat; + + +ALTER TABLE t1 DROP COLUMN b; +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +DROP INDEX idx2 ON t1; +SHOW CREATE TABLE t1; +SELECT * FROM mysql.index_stat; + +DROP INDEX idx1 ON t1; +DROP INDEX idx4 ON t1; +SHOW CREATE TABLE t1; + +ALTER TABLE t1 ADD COLUMN b varchar(32); +CREATE INDEX idx1 ON t1(b, e); +CREATE INDEX idx2 ON t1(c, d); +CREATE INDEX idx4 ON t1(e, b, d); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +UPDATE t1 SET b=(SELECT b FROM t0 WHERE t0.a= t1.a); +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 DROP COLUMN b, + DROP INDEX idx1, DROP INDEX idx2, DROP INDEX idx4; +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + +ALTER TABLE t1 ADD COLUMN b varchar(32); +ALTER TABLE t1 + ADD INDEX idx1 (b, e), ADD INDEX idx2 (c, d), ADD INDEX idx4 (e, b, d); +UPDATE t1 SET b=(SELECT b FROM t0 WHERE t0.a= t1.a); +SHOW CREATE TABLE t1; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(b) INDEXES(idx1, idx2, idx4); +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; @@ -297,7 +471,14 @@ SELECT UPPER(db_name), UPPER(table_name), use test; DROP DATABASE world; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; + DROP DATABASE world_innodb; +SELECT * FROM mysql.table_stat; +SELECT * FROM mysql.column_stat; +SELECT * FROM mysql.index_stat; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 0031da0c6b2..79f1c32ab1d 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -9649,7 +9649,8 @@ unlock_tables_n_open_system_tables_for_write(THD *thd, DBUG_ENTER("unlock_tables_n_open_system_tables_for_write"); - mysql_unlock_tables(thd, thd->lock); + if (thd->lock) + mysql_unlock_tables(thd, thd->lock); thd->lock= 0; lex->reset_n_backup_query_tables_list(&query_tables_list_backup); diff --git a/sql/sql_base.h b/sql/sql_base.h index 44d107376b0..6c20022f7ee 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -315,6 +315,13 @@ int open_and_lock_tables_derived(THD *thd, TABLE_LIST *tables, bool derived); int read_statistics_for_table(THD *thd, TABLE *table); int collect_statistics_for_table(THD *thd, TABLE *table); int update_statistics_for_table(THD *thd, TABLE *table); +int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab); +int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col); +int delete_statistics_for_index(THD *thd, TABLE *tab, KEY *key_info); +int rename_table_in_stat_tables(THD *thd, LEX_STRING *db, LEX_STRING *tab, + LEX_STRING *new_db, LEX_STRING *new_tab); +int rename_column_in_stat_tables(THD *thd, TABLE *tab, Field *col, + const char *new_name); void set_statistics_for_table(THD *thd, TABLE *table); extern "C" int simple_raw_key_cmp(void* arg, const void* key1, diff --git a/sql/sql_db.cc b/sql/sql_db.cc index 052616f6965..28565b02c1f 100644 --- a/sql/sql_db.cc +++ b/sql/sql_db.cc @@ -825,6 +825,17 @@ bool mysql_rm_db(THD *thd,char *db,bool if_exists, bool silent) lock_db_routines(thd, db)) goto exit; + if (!in_bootstrap) + { + for (table= tables; table; table= table->next_local) + { + LEX_STRING db_name= { table->db, table->db_length }; + LEX_STRING table_name= { table->table_name, table->table_name_length }; + if (table->open_type == OT_BASE_ONLY || !find_temporary_table(thd, table)) + (void) delete_statistics_for_table(thd, &db_name, &table_name); + } + } + /* mysql_ha_rm_tables() requires a non-null TABLE_LIST. */ if (tables) mysql_ha_rm_tables(thd, tables); diff --git a/sql/sql_rename.cc b/sql/sql_rename.cc index 6b0d1e980f9..d27989c3b01 100644 --- a/sql/sql_rename.cc +++ b/sql/sql_rename.cc @@ -279,6 +279,12 @@ do_rename(THD *thd, TABLE_LIST *ren_table, char *new_db, char *new_table_name, ren_table->db, old_alias, new_db, new_alias, 0))) { + LEX_STRING db_name= { ren_table->db, ren_table->db_length }; + LEX_STRING table_name= { ren_table->table_name, + ren_table->table_name_length }; + LEX_STRING new_table= { (char *) new_alias, strlen(new_alias) }; + (void) rename_table_in_stat_tables(thd, &db_name, &table_name, + &db_name, &new_table); if ((rc= Table_triggers_list::change_table_name(thd, ren_table->db, old_alias, ren_table->table_name, diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index de5f2976053..3e3815b6479 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -57,16 +57,20 @@ static const uint STATISTICS_TABLES= 3; /* - The names of the statistical tables in this list must correspond the + The names of the statistical tables in this array must correspond the definitions of the tables in the file ../scripts/mysql_system_tables.sql */ -static const char *STAT_TABLE_NAME[STATISTICS_TABLES]= +static const LEX_STRING stat_table_name[STATISTICS_TABLES]= { - "table_stat", - "column_stat", - "index_stat" + { C_STRING_WITH_LEN("table_stat") }, + { C_STRING_WITH_LEN("column_stat") }, + { C_STRING_WITH_LEN("index_stat") } }; +/* Name of database to which the statistical tables belong */ +static const LEX_STRING stat_tables_db_name= { C_STRING_WITH_LEN("mysql") }; + + /** @details The function builds a list of TABLE_LIST elements for system statistical @@ -74,6 +78,7 @@ static const char *STAT_TABLE_NAME[STATISTICS_TABLES]= The lock type of each element is set to TL_READ if for_write = FALSE, otherwise it is set to TL_WRITE. */ + inline void init_table_list_for_stat_tables(TABLE_LIST *tables, bool for_write) { uint i; @@ -82,21 +87,48 @@ inline void init_table_list_for_stat_tables(TABLE_LIST *tables, bool for_write) for (i= 0; i < STATISTICS_TABLES; i++) { - tables[i].db= (char*) "mysql"; - tables[i].table_name= (char *) STAT_TABLE_NAME[i]; - tables[i].alias= tables[i].table_name; + tables[i].db= stat_tables_db_name.str; + tables[i].db_length= stat_tables_db_name.length; + tables[i].alias= tables[i].table_name= stat_table_name[i].str; + tables[i].table_name_length= stat_table_name[i].length; tables[i].lock_type= for_write ? TL_WRITE : TL_READ; if (i < STATISTICS_TABLES - 1) tables[i].next_global= tables[i].next_local= tables[i].next_name_resolution_table= &tables[i+1]; + if (i != 0) + tables[i].prev_global= &tables[i-1].next_global; } } + +/** + @details + The function builds a TABLE_LIST containing only one element 'tbl' for + the statistical table called 'stat_tab_name'. + The lock type of the element is set to TL_READ if for_write = FALSE, + otherwise it is set to TL_WRITE. +*/ + +inline void init_table_list_for_single_stat_table(TABLE_LIST *tbl, + const LEX_STRING *stat_tab_name, + bool for_write) +{ + bzero((char *) tbl, sizeof(TABLE_LIST)); + + tbl->db= stat_tables_db_name.str; + tbl->db_length= stat_tables_db_name.length; + tbl->alias= tbl->table_name= stat_tab_name->str; + tbl->table_name_length= stat_tab_name->length; + tbl->lock_type= for_write ? TL_WRITE : TL_READ; +} + + /** @details The function sets null bits stored in the bitmap table_field->write_stat for all statistical values collected for a column. */ + inline void set_nulls_for_write_column_stat_values(Field *table_field) { table_field->write_stat.column_stat_nulls= @@ -104,11 +136,13 @@ inline void set_nulls_for_write_column_stat_values(Field *table_field) (COLUMN_STAT_COLUMN_NAME+1); } + /** @details The function sets null bits stored in the bitmap table_field->read_stat for all statistical values collected for a column. */ + inline void set_nulls_for_read_column_stat_values(Field *table_field) { table_field->read_stat.column_stat_nulls= @@ -116,50 +150,60 @@ inline void set_nulls_for_read_column_stat_values(Field *table_field) (COLUMN_STAT_COLUMN_NAME+1); } + /** @details The function removes the null bit stored in the bitmap table_field->write_stat for the statistical value collected on the statistical column number stat_field_no. */ + inline void set_not_null_for_write_column_stat_value(Field *table_field, uint stat_field_no) { table_field->write_stat.column_stat_nulls&= ~(1 << stat_field_no); } + /** @details The function removes the null bit stored in the bitmap table_field->read_stat for the statistical value collected on the statistical column number stat_field_no. */ + inline void set_not_null_for_read_column_stat_value(Field *table_field, uint stat_field_no) { table_field->read_stat.column_stat_nulls&= ~(1 << stat_field_no); } + /** @details The function checks the null bit stored in the bitmap table_field->read_stat for the statistical value collected on the statistical column number stat_field_no. */ + inline bool check_null_for_write_column_stat_value(Field *table_field, uint stat_field_no) { return table_field->write_stat.column_stat_nulls & (1 << stat_field_no); } + /* Stat_table is the base class for classes Table_stat, Column_stat and - Index_stat. The methods of these classes allow us table to read - statistical data from statistical tables and write collected statistical - data into statistical data. Objects of the classes Table_stat, Column_stat - and Index stat are used for reading/writing statistics from/into - persistent tables table_stat, column_stat and index_stat correspondingly. - These tables are stored in the system database 'mysql'. + Index_stat. The methods of these classes allow us to read statistical + data from statistical tables, write collected statistical data into + statistical tables and update statistical data in these tables + as well as update access fields belonging to the primary key and + delete records by prefixes of the primary key. + Objects of the classes Table_stat, Column_stat and Index stat are used + for reading/writing statistics from/into persistent tables table_stat, + column_stat and index_stat correspondingly. These tables are stored in + the system database 'mysql'. Statistics is read and written always for a given database table t. When an object of any of these classes is created a pointer to the TABLE @@ -168,9 +212,15 @@ inline bool check_null_for_write_column_stat_value(Field *table_field, the corresponding statistical table st. So construction of an object to read/write statistical data on table t from/into statistical table st requires both table t and st to be opened. + In some cases the TABLE structure for table t may be undefined. Then + the objects of the classes Table_stat, Column_stat and Index stat are + created by the alternative constructor that require only the name + of the table t and the name of the database it belongs to. Now the + alternative constructors are used only in the cases when some records + belonging to the table are to be deleted, or its keys are to be updated Reading/writing statistical data from/into a statistical table is always - performed by key. At the moment there is only one key defined for each + performed by a key. At the moment there is only one key defined for each statistical table and this key is primary. The primary key for the table table_stat is built as (db_name, table_name). The primary key for the table column_stat is built as (db_name, table_name, @@ -234,7 +284,7 @@ inline bool check_null_for_write_column_stat_value(Field *table_field, It is assumed that before any invocation of this method a call of the function st.set_key_fields has set the values of the primary key fields that serve to locate the row from the statistical table st where the - the colected statistical data from internal structures are to be written + the collected statistical data from internal structures are to be written to. The statistical data is written from the counterparts of the statistical fields of internal structures into which it would be read by the functions get_stat_values. The counterpart fields are used @@ -248,37 +298,18 @@ inline bool check_null_for_write_column_stat_value(Field *table_field, class Stat_table { + private: + /* Handler used for the retrieval of the statistical table stat_table */ handler *stat_file; - KEY *stat_key_info; /* Structure for the index to access stat_table */ - uint stat_key_length; /* Length of the key to access stat_table */ + uint stat_key_length; /* Length of the key to access stat_table */ uchar *record[2]; /* Record buffers used to access/update stat_table */ uint stat_key_idx; /* The number of the key to access stat_table */ -protected: - /* Statistical table to read statistics from or to update */ - TABLE *stat_table; - - /* Table for which statistical data is read / updated */ - TABLE *table; - char *db_name; /* Name of the database containing 'table' */ - uint db_name_len; /* Length of db_name */ - char *table_name; /* Name of the table 'table' */ - uint table_name_len; /* Name of table_name */ - -public: - - /* - @details - This constructor has to be called by any constructor of the derived - classes. The constructor 'tunes' the private and protected members of - the constructed object to the statistical table 'stat_table' with the - statistical data of our interest and to the table 'tab' for which this - statistics has been collected. - */ - Stat_table(TABLE *stat, TABLE *tab) :stat_table(stat), table(tab) + /* This is a helper function used only by the Stat_table constructors */ + void common_init_stat_table() { stat_file= stat_table->file; /* Currently any statistical table has only one key */ @@ -287,15 +318,97 @@ public: stat_key_length= stat_key_info->key_length; record[0]= stat_table->record[0]; record[1]= stat_table->record[1]; - db_name= table->s->db.str; - db_name_len= table->s->db.length; - table_name= table->s->table_name.str; - table_name_len= table->s->table_name.length; } +protected: + + /* Statistical table to read statistics from or to update/delete */ + TABLE *stat_table; + KEY *stat_key_info; /* Structure for the index to access stat_table */ + + /* Table for which statistical data is read / updated */ + TABLE *table; + LEX_STRING *db_name; /* Name of the database containing 'table' */ + LEX_STRING *table_name; /* Name of the table 'table' */ + + void store_record_for_update() + { + store_record(stat_table, record[1]); + } + + void store_record_for_lookup() + { + store_record(stat_table, record[0]); + } + + bool update_record() + { + int err; + if ((err= stat_file->ha_update_row(record[1], record[0])) && + err != HA_ERR_RECORD_IS_THE_SAME) + return TRUE; + return FALSE; + } + +public: + + + /** + @details + This constructor has to be called by any constructor of the derived + classes. The constructor 'tunes' the private and protected members of + the constructed object to the statistical table 'stat_table' with the + statistical data of our interest and to the table 'tab' for which this + statistics has been collected. + */ + + Stat_table(TABLE *stat, TABLE *tab) :stat_table(stat), table(tab) + { + common_init_stat_table(); + db_name= &table->s->db; + table_name= &table->s->table_name; + } + + + /** + @details + This constructor has to be called by any constructor of the derived + classes. The constructor 'tunes' the private and protected members of + the constructed object to the statistical table 'stat_table' with the + statistical data of our interest and to the table t for which this + statistics has been collected. The table t is uniquely specified + by the database name 'db' and the table name 'tab'. + */ + + Stat_table(TABLE *stat, LEX_STRING *db, LEX_STRING *tab) + :stat_table(stat), table(NULL) + { + common_init_stat_table(); + db_name= db; + table_name= tab; + } + + virtual ~Stat_table() {} - /* + /** + @brief + Store the given values of fields for database name and table name + + @details + This is a purely virtual method. + The implementation for any derived class shall store the given + values of the database name and table name in the corresponding + fields of stat_table. + + @note + The method is called by the update_table_name_key_parts function. + */ + + virtual void change_full_table_name(LEX_STRING *db, LEX_STRING *tab)= 0; + + + /** @brief Store statistical data into fields of the statistical table @@ -307,9 +420,11 @@ public: @note The method is called by the update_stat function. */ + virtual void store_stat_fields()= 0; - /* + + /** @brief Read statistical data from fields of the statistical table @@ -318,11 +433,13 @@ public: The implementation for any derived read shall read the appropriate statistical data from the corresponding fields of stat_table. */ + virtual void get_stat_values()= 0; - /* - @breif - Find a record by key in the statistical table + + /** + @brief + Find a record in the statistical table by a primary key @details The function looks for a record in stat_table by its primary key. @@ -334,6 +451,7 @@ public: @retval TRUE the record is found */ + bool find_stat() { uchar key[MAX_KEY_LENGTH]; @@ -342,8 +460,38 @@ public: HA_WHOLE_KEY, HA_READ_KEY_EXACT); } - /* - @breif + + /** + @brief + Find a record in the statistical table by a key prefix value + + @details + The function looks for a record in stat_table by the key value consisting + of 'prefix_parts' major components for the primary index. + It assumes that the key prefix fields have been already stored in the record + buffer of stat_table. + + @retval + FALSE the record is not found + @retval + TRUE the record is found + */ + + bool find_next_stat_for_prefix(uint prefix_parts) + { + uchar key[MAX_KEY_LENGTH]; + uint prefix_key_length= 0; + for (uint i= 0; i < prefix_parts; i++) + prefix_key_length+= stat_key_info->key_part[i].store_length; + key_copy(key, record[0], stat_key_info, prefix_key_length); + key_part_map prefix_map= (key_part_map) ((1 << prefix_parts) - 1); + return !stat_file->ha_index_read_idx_map(record[0], stat_key_idx, key, + prefix_map, HA_READ_KEY_EXACT); + } + + + /** + @brief Update/insert a record in the statistical table with new statistics @details @@ -365,58 +513,141 @@ public: The function calls the virtual method store_stat_fields to populate the statistical fields of the updated/inserted row with new statistics. */ + bool update_stat() { - int err; if (find_stat()) { - store_record(stat_table, record[1]); + store_record_for_update(); store_stat_fields(); - if ((err= stat_file->ha_update_row(record[1], record[0])) && - err != HA_ERR_RECORD_IS_THE_SAME) - return TRUE; + return update_record(); } else { + int err; store_stat_fields(); if ((err= stat_file->ha_write_row(record[0]))) return TRUE; } return FALSE; } + + /** + @brief + Update the table name fields in the current record of stat_table + + @details + The function updates the fields containing database name and table name + for the last found record in the statistical table stat_table. + The corresponding names for update is taken from the parameters + db and tab. + + @retval + FALSE success with the update of the record + @retval + TRUE failure with the update of the record + + @note + The function calls the virtual method change_full_table_name + to store the new names in the record buffer used for updates. + */ + + bool update_table_name_key_parts(LEX_STRING *db, LEX_STRING *tab) + { + store_record_for_update(); + change_full_table_name(db, tab); + bool rc= update_record(); + store_record_for_lookup(); + return rc; + } + + + /** + @brief + Delete the current record of the statistical table stat_table + + @details + The function deletes the last found record from the statistical + table stat_table. + + @retval + FALSE success with the deletion of the record + @retval + TRUE failure with the deletion of the record + */ + + bool delete_stat() + { + int err; + if ((err= stat_file->ha_delete_row(record[0]))) + return TRUE; + return FALSE; + } }; /* An object of the class Table_stat is created to read statistical - data on tables from the statistical table table_stat or to update - table_stat with such statistical data. + data on tables from the statistical table table_stat, to update + table_stat with such statistical data, or to update columns + of the primary key, or to delete the record by its primary key or + its prefix. Rows from the statistical table are read and updated always by primary key. */ class Table_stat: public Stat_table { + private: + Field *db_name_field; /* Field for the column table_stat.db_name */ Field *table_name_field; /* Field for the column table_stat.table_name */ + void common_init_table_stat() + { + db_name_field= stat_table->field[TABLE_STAT_DB_NAME]; + table_name_field= stat_table->field[TABLE_STAT_TABLE_NAME]; + } + + void change_full_table_name(LEX_STRING *db, LEX_STRING *tab) + { + db_name_field->store(db->str, db->length, system_charset_info); + table_name_field->store(tab->str, tab->length, system_charset_info); + } + public: - /* + /** @details The constructor 'tunes' the private and protected members of the constructed object for the statistical table table_stat to read/update statistics on table 'tab'. The TABLE structure for the table table_stat must be passed as a value for the parameter 'stat'. */ + Table_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) { - db_name_field= stat_table->field[TABLE_STAT_DB_NAME]; - table_name_field= stat_table->field[TABLE_STAT_TABLE_NAME]; + common_init_table_stat(); } - /* + + /** + @details + The constructor 'tunes' the private and protected members of the + object constructed for the statistical table table_stat for + the future updates/deletes of the record concerning the table 'tab' + from the database 'db'. + */ + + Table_stat(TABLE *stat, LEX_STRING *db, LEX_STRING *tab) + :Stat_table(stat, db, tab) + { + common_init_table_stat(); + } + + + /** @brief Set the key fields for the statistical table table_stat @@ -429,13 +660,16 @@ public: The function is supposed to be called before any use of the method find_stat for an object of the Table_stat class. */ + void set_key_fields() { - db_name_field->store(db_name, db_name_len, &my_charset_bin); - table_name_field->store(table_name, table_name_len, &my_charset_bin); + db_name_field->store(db_name->str, db_name->length, system_charset_info); + table_name_field->store(table_name->str, table_name->length, + system_charset_info); } - /* + + /** @brief Store statistical data into statistical fields of table_stat @@ -445,6 +679,7 @@ public: the value of the flag write_stat.cardinality_is_null and the value of the field write_stat.cardinality' from the TABLE structure for 'table'. */ + void store_stat_fields() { Field *stat_field= stat_table->field[TABLE_STAT_CARDINALITY]; @@ -457,7 +692,8 @@ public: } } - /* + + /** @brief Read statistical data from statistical fields of table_stat @@ -470,6 +706,7 @@ public: and the value of the field read_stat.cardinality' from the TABLE structure for 'table' accordingly. */ + void get_stat_values() { table->read_stat.cardinality_is_null= TRUE; @@ -490,63 +727,140 @@ public: /* An object of the class Column_stat is created to read statistical data - on table columns from the statistical table column_stat or to update - column_stat with such statistical data. + on table columns from the statistical table column_stat, to update + column_stat with such statistical data, or to update columns + of the primary key, or to delete the record by its primary key or + its prefix. Rows from the statistical table are read and updated always by primary key. */ class Column_stat: public Stat_table { + private: + Field *db_name_field; /* Field for the column column_stat.db_name */ Field *table_name_field; /* Field for the column column_stat.table_name */ Field *column_name_field; /* Field for the column column_stat.column_name */ Field *table_field; /* Field from 'table' to read /update statistics on */ -public: - - /* - @details - The constructor 'tunes' the private and protected members of the - constructed object for the statistical table column_stat to read/update - statistics on fields of the table 'tab'. The TABLE structure for the table - column_stat must be passed as a value for the parameter 'stat'. - */ - Column_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + void common_init_column_stat_table() { db_name_field= stat_table->field[COLUMN_STAT_DB_NAME]; table_name_field= stat_table->field[COLUMN_STAT_TABLE_NAME]; column_name_field= stat_table->field[COLUMN_STAT_COLUMN_NAME]; } - /* + void change_full_table_name(LEX_STRING *db, LEX_STRING *tab) + { + db_name_field->store(db->str, db->length, system_charset_info); + table_name_field->store(tab->str, tab->length, system_charset_info); + } + +public: + + /** + @details + The constructor 'tunes' the private and protected members of the + constructed object for the statistical table column_stat to read/update + statistics on fields of the table 'tab'. The TABLE structure for the table + column_stat must be passed as a value for the parameter 'stat'. + */ + + Column_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + { + common_init_column_stat_table(); + } + + + /** + @details + The constructor 'tunes' the private and protected members of the + object constructed for the statistical table column_stat for + the future updates/deletes of the record concerning the table 'tab' + from the database 'db'. + */ + + Column_stat(TABLE *stat, LEX_STRING *db, LEX_STRING *tab) + :Stat_table(stat, db, tab) + { + common_init_column_stat_table(); + } + + /** + @brief + Set table name fields for the statistical table column_stat + + @details + The function stores the values of the fields db_name and table_name + of the statistical table column_stat in the record buffer. + */ + + void set_full_table_name() + { + db_name_field->store(db_name->str, db_name->length, system_charset_info); + table_name_field->store(table_name->str, table_name->length, + system_charset_info); + } + + + /** @brief Set the key fields for the statistical table column_stat @param - column Field for the 'table' column to read/update statistics on + col Field for the 'table' column to read/update statistics on @details - The function sets the values of the fields db_name, table_name and + The function stores the values of the fields db_name, table_name and column_name in the record buffer for the statistical table column_stat. These fields comprise the primary key for the table. + It also sets table_field to the passed parameter. @note The function is supposed to be called before any use of the method find_stat for an object of the Column_stat class. */ - void set_key_fields(Field *column) + + void set_key_fields(Field *col) { - db_name_field->store(db_name, db_name_len, &my_charset_bin); - table_name_field->store(table_name, table_name_len, &my_charset_bin); - table_field= column; - const char *column_name= column->field_name; - column_name_field->store(column_name, strlen(column_name), &my_charset_bin); + set_full_table_name(); + const char *column_name= col->field_name; + column_name_field->store(column_name, strlen(column_name), + system_charset_info); + table_field= col; } - /* + + /** + @brief + Update the table name fields in the current record of stat_table + + @details + The function updates the primary key fields containing database name, + table name, and column name for the last found record in the statistical + table column_stat. + + @retval + FALSE success with the update of the record + @retval + TRUE failure with the update of the record + */ + + bool update_column_key_part(const char *col) + { + store_record_for_update(); + set_full_table_name(); + column_name_field->store(col, strlen(col), system_charset_info); + bool rc= update_record(); + store_record_for_lookup(); + return rc; + } + + + /** @brief Store statistical data into statistical fields of column_stat @@ -567,6 +881,7 @@ public: is less than the length of the string the string is trimmed to fit the length of the column. */ + void store_stat_fields() { char buff[MAX_FIELD_WIDTH]; @@ -613,7 +928,8 @@ public: } } - /* + + /** @brief Read statistical data from statistical fields of column_stat @@ -628,6 +944,7 @@ public: max_value, nulls_ratio, avg_length and avg_frequency of the structure read_stat from the Field structure for the field 'table_field'. */ + void get_stat_values() { set_nulls_for_read_column_stat_values(table_field); @@ -684,15 +1001,19 @@ public: /* An object of the class Index_stat is created to read statistical - data on index prefixes from the statistical table index_stat or - to update index_stat with such statistical data. - Rows from the statistical table are read and updated always by - primary key. + data on tables from the statistical table table_stat, to update + index_stat with such statistical data, or to update columns + of the primary key, or to delete the record by its primary key or + its prefix. + Rows from the statistical table are read and updated always by + primary key. */ class Index_stat: public Stat_table { + private: + Field *db_name_field; /* Field for the column index_stat.db_name */ Field *table_name_field; /* Field for the column index_stat.table_name */ Field *index_name_field; /* Field for the column index_stat.table_name */ @@ -701,9 +1022,24 @@ private: KEY *table_key_info; /* Info on the index to read/update statistics on */ uint prefix_arity; /* Number of components of the index prefix of interest */ + void common_init_index_stat_table() + { + db_name_field= stat_table->field[INDEX_STAT_DB_NAME]; + table_name_field= stat_table->field[INDEX_STAT_TABLE_NAME]; + index_name_field= stat_table->field[INDEX_STAT_INDEX_NAME]; + prefix_arity_field= stat_table->field[INDEX_STAT_PREFIX_ARITY]; + } + + void change_full_table_name(LEX_STRING *db, LEX_STRING *tab) + { + db_name_field->store(db->str, db->length, system_charset_info); + table_name_field->store(tab->str, tab->length, system_charset_info); + } + public: - /* + + /** @details The constructor 'tunes' the private and protected members of the constructed object for the statistical table index_stat to read/update @@ -713,14 +1049,69 @@ public: */ Index_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) { - db_name_field= stat_table->field[INDEX_STAT_DB_NAME]; - table_name_field= stat_table->field[INDEX_STAT_TABLE_NAME]; - index_name_field= stat_table->field[INDEX_STAT_INDEX_NAME]; - prefix_arity_field= stat_table->field[INDEX_STAT_PREFIX_ARITY]; - - } + common_init_index_stat_table(); + } - /* + + /** + @details + The constructor 'tunes' the private and protected members of the + object constructed for the statistical table index_stat for + the future updates/deletes of the record concerning the table 'tab' + from the database 'db'. + */ + + Index_stat(TABLE *stat, LEX_STRING *db, LEX_STRING *tab) + :Stat_table(stat, db, tab) + { + common_init_index_stat_table(); + } + + + /** + @brief + Set table name fields for the statistical table index_stat + + @details + The function stores the values of the fields db_name and table_name + of the statistical table index_stat in the record buffer. + */ + + void set_full_table_name() + { + db_name_field->store(db_name->str, db_name->length, system_charset_info); + table_name_field->store(table_name->str, table_name->length, + system_charset_info); + } + + /** + @brief + Set the key fields of index_stat used to access records for index prefixes + + @param + index_info Info for the index of 'table' to read/update statistics on + + @details + The function sets the values of the fields db_name, table_name and + index_name in the record buffer for the statistical table index_stat. + It also sets table_key_info to the passed parameter. + + @note + The function is supposed to be called before any use of the method + find_next_stat_for_prefix for an object of the Index_stat class. + */ + + void set_index_prefix_key_fields(KEY *index_info) + { + set_full_table_name(); + char *index_name= index_info->name; + index_name_field->store(index_name, strlen(index_name), + system_charset_info); + table_key_info= index_info; + } + + + /** @brief Set the key fields for the statistical table index_stat @@ -729,7 +1120,6 @@ public: @param index_prefix_arity Number of components in the index prefix of interest - @details The function sets the values of the fields db_name, table_name and index_name, prefix_arity in the record buffer for the statistical @@ -739,20 +1129,18 @@ public: The function is supposed to be called before any use of the method find_stat for an object of the Index_stat class. */ - void set_key_fields(KEY *index_info, uint index_prefix_arity) + + void set_key_fields(KEY *index_info, uint index_prefix_arity) { - db_name_field->store(db_name, db_name_len, &my_charset_bin); - table_name_field->store(table_name, table_name_len, &my_charset_bin); - table_key_info= index_info; - char *index_name= index_info->name; - index_name_field->store(index_name, strlen(index_name), &my_charset_bin); + set_index_prefix_key_fields(index_info); prefix_arity= index_prefix_arity; prefix_arity_field->store(index_prefix_arity, TRUE); } - /* + + /** @brief - Store statistical data into statistical fields of tableindex_stat + Store statistical data into statistical fields of table index_stat @details This implementation of a purely virtual method sets the value of the @@ -762,6 +1150,7 @@ public: If the value of write_stat. avg_frequency[Index_stat::prefix_arity] is equal to 0, the value of the column is set to NULL. */ + void store_stat_fields() { Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; @@ -776,7 +1165,8 @@ public: } } - /* + + /** @brief Read statistical data from statistical fields of index_stat @@ -791,6 +1181,7 @@ public: set to 0. Otherwise, read_stat.avg_frequency[Index_stat::prefix_arity] is set to the value of the column. */ + void get_stat_values() { double avg_frequency= 0; @@ -826,12 +1217,12 @@ protected: public: - /* + /** @param field Field for which the number of distinct values is to be find out @param - max_heap_table_size The linit for the memory used by the RB tree container + max_heap_table_size The limit for the memory used by the RB tree container of the constructed Unique object 'tree' @details @@ -840,6 +1231,7 @@ public: The type of 'field' and the value max_heap_table_size of determine the set of the parameters to be passed to the constructor of the Unique object. */ + Count_distinct_field(Field *field, uint max_heap_table_size) { qsort_cmp2 compare_key; @@ -874,7 +1266,7 @@ public: /* @brief - Check whether the Unique object tree has been succesfully created + Check whether the Unique object tree has been successfully created */ bool exists() { @@ -941,7 +1333,9 @@ public: class Index_prefix_calc: public Sql_alloc { + private: + /* Table containing index specified by index_info */ TABLE *index_table; /* Info for the index i for whose prefix 'avg_frequency' is calculated */ @@ -964,7 +1358,7 @@ private: the last encountered k-component prefix */ ulonglong prefix_count; - /* The values of the last encoutered k-component prefix */ + /* The values of the last encountered k-component prefix */ Cached_item *last_prefix; }; @@ -975,6 +1369,7 @@ private: Prefix_calc_state *calc_state; public: + Index_prefix_calc(TABLE *table, KEY *key_info) : index_table(table), index_info(key_info) { @@ -1006,7 +1401,7 @@ public: } } - /* + /** @breif Change the elements of calc_state after reading the next index entry @@ -1020,6 +1415,7 @@ public: any of these k components has changed. If so, the value of calc_state[k-1].prefix_count is incremented by 1. */ + void add() { uint i; @@ -1045,7 +1441,7 @@ public: } } - /* + /** @brief Calculate the values of avg_frequency for all prefixes of an index @@ -1057,6 +1453,7 @@ public: If calc_state[k-1].prefix_count happens to be 0, the value of avg_frequency[k-1] is set to 0, i.e. is considered as unknown. */ + void get_avg_frequency() { uint i; @@ -1272,7 +1669,7 @@ int collect_statistics_for_table(THD *thd, TABLE *table) Field **field_ptr; Field *table_field; ha_rows rows= 0; - handler *file=table->file; + handler *file=table->file; DBUG_ENTER("collect_statistics_for_table"); @@ -1358,25 +1755,34 @@ int collect_statistics_for_table(THD *thd, TABLE *table) table_field= *field_ptr; if (!bitmap_is_set(table->read_set, table_field->field_index)) continue; - val= (double) table_field->nulls / rows; - table_field->write_stat.set_nulls_ratio(val); - val= (double) table_field->column_total_length / (rows-table_field->nulls); - table_field->write_stat.set_avg_length(val); - if (table_field->count_distinct) + if (rows) { - val= (double) (rows-table_field->nulls) / - table_field->count_distinct->get_value(); - table_field->write_stat.set_avg_frequency(val); + val= (double) table_field->nulls / rows; + table_field->write_stat.set_nulls_ratio(val); set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_AVG_FREQUENCY); + COLUMN_STAT_NULLS_RATIO); + } + if (rows-table_field->nulls) + { + val= (double) table_field->column_total_length / (rows-table_field->nulls); + table_field->write_stat.set_avg_length(val); + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_AVG_LENGTH); + } + if (table_field->count_distinct) + { + ulonglong count_distinct= table_field->count_distinct->get_value(); + if (count_distinct) + { + val= (double) (rows-table_field->nulls) / count_distinct; + table_field->write_stat.set_avg_frequency(val); + set_not_null_for_write_column_stat_value(table_field, + COLUMN_STAT_AVG_FREQUENCY); + } delete table_field->count_distinct; table_field->count_distinct= NULL; } - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_NULLS_RATIO); - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_AVG_LENGTH); } } @@ -1409,7 +1815,7 @@ int collect_statistics_for_table(THD *thd, TABLE *table) @details For each statistical table st the function looks for the rows from this table that contain statistical data on 'table'. If rows with given - statistical characteritics exist they are updated with the new statistical + statistical characteristics exist they are updated with the new statistical values taken from internal structures for 'table'. Otherwise new rows with these statistical characteristics are added into st. It is assumed that values stored in the statistical tables are found and @@ -1451,7 +1857,10 @@ int update_statistics_for_table(THD *thd, TABLE *table) if (unlock_tables_n_open_system_tables_for_write(thd, tables, &open_tables_backup)) - DBUG_RETURN(1); + { + thd->clear_error(); + DBUG_RETURN(rc); + } /* Update the statistical table table_stat */ stat_table= tables[TABLE_STAT].table; @@ -1473,7 +1882,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) restore_record(stat_table, s->default_values); column_stat.set_key_fields(table_field); err= column_stat.update_stat(); - if (err & !rc) + if (err && !rc) rc= 1; } @@ -1492,7 +1901,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) restore_record(stat_table, s->default_values); index_stat.set_key_fields(key_info, i+1); err= index_stat.update_stat(); - if (err & !rc) + if (err && !rc) rc= 1; } } @@ -1521,7 +1930,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) The function is called in function open_tables. @retval - 0 If data has been succesfully read from all statistical tables + 0 If data has been successfully read from all statistical tables @retval 1 Otherwise @@ -1552,11 +1961,14 @@ int read_statistics_for_table(THD *thd, TABLE *table) init_mdl_requests(tables); if (open_system_tables_for_read(thd, tables, &open_tables_backup)) - DBUG_RETURN(1); + { + thd->clear_error(); + DBUG_RETURN(0); + } create_min_max_stistical_fields(table, FALSE); - /* Read statistics from the statistical table index_stat */ + /* Read statistics from the statistical table table_stat */ stat_table= tables[TABLE_STAT].table; Table_stat table_stat(stat_table, table); table_stat.set_key_fields(); @@ -1637,6 +2049,369 @@ int read_statistics_for_table(THD *thd, TABLE *table) } +/** + @brief + Delete statistics on a table from all statistical tables + + @param + thd The thread handle + @param + db The name of the database the table belongs to + @param + tab The name of the table whose statistics is to be deleted + + @details + The function delete statistics on the table called 'tab' of the database + 'db' from all statistical tables: table_stat, column_stat, index_stat. + + @retval + 0 If all deletions are successful + @retval + 1 Otherwise + + @note + The function is called when executing the statement DROP TABLE 'tab'. +*/ + +int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab) +{ + int err; + TABLE *stat_table; + TABLE_LIST tables[STATISTICS_TABLES]; + Open_tables_backup open_tables_backup; + int rc= 0; + + DBUG_ENTER("delete_statistics_for_table"); + + init_table_list_for_stat_tables(tables, TRUE); + init_mdl_requests(tables); + + if (open_system_tables_for_read(thd, + tables, + &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(rc); + } + + /* Delete statistics on table from the statistical table index_stat */ + stat_table= tables[INDEX_STAT].table; + Index_stat index_stat(stat_table, db, tab); + index_stat.set_full_table_name(); + while (index_stat.find_next_stat_for_prefix(2)) + { + err= index_stat.delete_stat(); + if (err & !rc) + rc= 1; + } + + /* Delete statistics on table from the statistical table column_stat */ + stat_table= tables[COLUMN_STAT].table; + Column_stat column_stat(stat_table, db, tab); + column_stat.set_full_table_name(); + while (column_stat.find_next_stat_for_prefix(2)) + { + err= column_stat.delete_stat(); + if (err & !rc) + rc= 1; + } + + /* Delete statistics on table from the statistical table table_stat */ + stat_table= tables[TABLE_STAT].table; + Table_stat table_stat(stat_table, db, tab); + table_stat.set_key_fields(); + if (table_stat.find_stat()) + { + err= table_stat.delete_stat(); + if (err & !rc) + rc= 1; + } + + close_system_tables(thd, &open_tables_backup); + + DBUG_RETURN(rc); +} + + +/** + @brief + Delete statistics on a column of the specified table + + @param + thd The thread handle + @param + tab The table the column belongs to + @param + col The field of the column whose statistics is to be deleted + + @details + The function delete statistics on the column 'col' belonging to the table + 'tab' from the statistical table column_stat. + + @retval + 0 If the deletion is successful + @retval + 1 Otherwise + + @note + The function is called when dropping a table column or when changing + the definition of this column. +*/ + +int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col) +{ + int err; + TABLE *stat_table; + TABLE_LIST tables; + Open_tables_backup open_tables_backup; + int rc= 0; + + DBUG_ENTER("delete_statistics_for_column"); + + init_table_list_for_single_stat_table(&tables, &stat_table_name[1], TRUE); + init_mdl_requests(&tables); + + if (open_system_tables_for_read(thd, + &tables, + &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(rc); + } + + stat_table= tables.table; + Column_stat column_stat(stat_table, tab); + column_stat.set_key_fields(col); + if (column_stat.find_stat()) + { + err= column_stat.delete_stat(); + if (err) + rc= 1; + } + + close_system_tables(thd, &open_tables_backup); + + DBUG_RETURN(rc); +} + + +/** + @brief + Delete statistics on an index of the specified table + + @param + thd The thread handle + @param + tab The table the index belongs to + @param + key_info The descriptor of the index whose statistics is to be deleted + + @details + The function delete statistics on the index specified by 'key_info' + defined on the table 'tab' from the statistical table index_stat. + + @retval + 0 If the deletion is successful + @retval + 1 Otherwise + + @note + The function is called when dropping an index, or dropping/changing the + definition of a column used in the definition of the index. +*/ + +int delete_statistics_for_index(THD *thd, TABLE *tab, KEY *key_info) +{ + int err; + TABLE *stat_table; + TABLE_LIST tables; + Open_tables_backup open_tables_backup; + int rc= 0; + + DBUG_ENTER("delete_statistics_for_index"); + + init_table_list_for_single_stat_table(&tables, &stat_table_name[2], TRUE); + init_mdl_requests(&tables); + + if (open_system_tables_for_read(thd, + &tables, + &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(rc); + } + + stat_table= tables.table; + Index_stat index_stat(stat_table, tab); + index_stat.set_index_prefix_key_fields(key_info); + while (index_stat.find_next_stat_for_prefix(3)) + { + err= index_stat.delete_stat(); + if (err && !rc) + rc= 1; + } + + close_system_tables(thd, &open_tables_backup); + + DBUG_RETURN(rc); +} + + +/** + @brief + Rename a table in all statistical tables + + @param + thd The thread handle + @param + db The name of the database the table belongs to + @param + tab The name of the table to be renamed in statistical tables + @param + new_tab The new name of the table + + @details + The function replaces the name of the table 'tab' from the database 'db' + for 'new_tab' in all all statistical tables: table_stat, column_stat, + index_stat. + + @retval + 0 If all updates of the table name are successful + @retval + 1 Otherwise + + @note + The function is called when executing any statement that renames a table +*/ + +int rename_table_in_stat_tables(THD *thd, LEX_STRING *db, LEX_STRING *tab, + LEX_STRING *new_db, LEX_STRING *new_tab) +{ + int err; + TABLE *stat_table; + TABLE_LIST tables[STATISTICS_TABLES]; + Open_tables_backup open_tables_backup; + int rc= 0; + + DBUG_ENTER("rename_table_in_stat_tables"); + + init_table_list_for_stat_tables(tables, TRUE); + init_mdl_requests(tables); + + if (open_system_tables_for_read(thd, + tables, + &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(rc); + } + + /* Rename table in the statistical table index_stat */ + stat_table= tables[INDEX_STAT].table; + Index_stat index_stat(stat_table, db, tab); + index_stat.set_full_table_name(); + while (index_stat.find_next_stat_for_prefix(2)) + { + err= index_stat.update_table_name_key_parts(new_db, new_tab); + if (err & !rc) + rc= 1; + index_stat.set_full_table_name(); + } + + /* Rename table in the statistical table column_stat */ + stat_table= tables[COLUMN_STAT].table; + Column_stat column_stat(stat_table, db, tab); + column_stat.set_full_table_name(); + while (column_stat.find_next_stat_for_prefix(2)) + { + err= column_stat.update_table_name_key_parts(new_db, new_tab); + if (err & !rc) + rc= 1; + column_stat.set_full_table_name(); + } + + /* Rename table in the statistical table table_stat */ + stat_table= tables[TABLE_STAT].table; + Table_stat table_stat(stat_table, db, tab); + table_stat.set_key_fields(); + if (table_stat.find_stat()) + { + err= table_stat.update_table_name_key_parts(new_db, new_tab); + if (err & !rc) + rc= 1; + } + + close_system_tables(thd, &open_tables_backup); + + DBUG_RETURN(rc); +} + + +/** + @brief + Rename a column in the statistical table column_stat + + @param + thd The thread handle + @param + tab The table the column belongs to + @param + col The column to be renamed + @param + new_name The new column name + + @details + The function replaces the name of the column 'col' belonging to the table + 'tab' for 'new_name' in the statistical table column_stat.. + + @retval + 0 If all updates of the table name are successful + @retval + 1 Otherwise + + @note + The function is called when executing any statement that renames a column, + but does not change the column definition. +*/ + +int rename_column_in_stat_tables(THD *thd, TABLE *tab, Field *col, + const char *new_name) +{ + int err; + TABLE *stat_table; + TABLE_LIST tables; + Open_tables_backup open_tables_backup; + int rc= 0; + + DBUG_ENTER("rename_column_in_stat_tables"); + + init_table_list_for_single_stat_table(&tables, &stat_table_name[1], TRUE); + init_mdl_requests(&tables); + + if (open_system_tables_for_read(thd, + &tables, + &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(rc); + } + + /* Rename column in the statistical table table_stat */ + stat_table= tables.table; + Column_stat column_stat(stat_table, tab); + column_stat.set_key_fields(col); + if (column_stat.find_stat()) + { + err= column_stat.update_column_key_part(new_name); + if (err & !rc) + rc= 1; + } + close_system_tables(thd, &open_tables_backup); + + DBUG_RETURN(rc); +} + + /** @brief Set statistics for a table that will be used by the optimizer diff --git a/sql/sql_table.cc b/sql/sql_table.cc index 031932b4c06..8557e0e598c 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -1878,6 +1878,17 @@ bool mysql_rm_table(THD *thd,TABLE_LIST *tables, my_bool if_exists, } } + if (!in_bootstrap) + { + for (table= tables; table; table= table->next_local) + { + LEX_STRING db_name= { table->db, table->db_length }; + LEX_STRING table_name= { table->table_name, table->table_name_length }; + if (table->open_type == OT_BASE_ONLY || !find_temporary_table(thd, table)) + (void) delete_statistics_for_table(thd, &db_name, &table_name); + } + } + mysql_ha_rm_tables(thd, tables); if (!drop_temporary) @@ -1888,6 +1899,7 @@ bool mysql_rm_table(THD *thd,TABLE_LIST *tables, my_bool if_exists, MYSQL_OPEN_SKIP_TEMPORARY)) DBUG_RETURN(true); for (table= tables; table; table= table->next_local) + tdc_remove_table(thd, TDC_RT_REMOVE_ALL, table->db, table->table_name, false); } @@ -5084,6 +5096,21 @@ mysql_compare_tables(TABLE *table, thd->calloc(sizeof(void*) * table->s->keys)) == NULL) DBUG_RETURN(1); + tmp_new_field_it.init(tmp_alter_info.create_list); + for (i= 0, f_ptr= table->field, tmp_new_field= tmp_new_field_it++; + (field= *f_ptr); + i++, f_ptr++, tmp_new_field= tmp_new_field_it++) + { + if (field->is_equal(tmp_new_field) == IS_EQUAL_NO && + table->s->tmp_table == NO_TMP_TABLE) + (void) delete_statistics_for_column(thd, table, field); + else if (my_strcasecmp(system_charset_info, + field->field_name, + tmp_new_field->field_name)) + (void) rename_column_in_stat_tables(thd, table, field, + tmp_new_field->field_name); + } + /* Use transformed info to evaluate possibility of in-place ALTER TABLE but use the preserved field to persist modifications. @@ -5144,7 +5171,12 @@ mysql_compare_tables(TABLE *table, if (my_strcasecmp(system_charset_info, field->field_name, tmp_new_field->field_name)) - field->flags|= FIELD_IS_RENAMED; + { + field->flags|= FIELD_IS_RENAMED; + if (table->s->tmp_table == NO_TMP_TABLE) + rename_column_in_stat_tables(thd, table, field, + tmp_new_field->field_name); + } /* Evaluate changes bitmap and send to check_if_incompatible_data() */ if (!(tmp= field->is_equal(tmp_new_field))) @@ -5247,6 +5279,8 @@ mysql_compare_tables(TABLE *table, field= table->field[key_part->fieldnr]; field->flags|= FIELD_IN_ADD_INDEX; } + if (table->s->tmp_table == NO_TMP_TABLE) + (void) delete_statistics_for_index(thd, table, table_key); DBUG_PRINT("info", ("index changed: '%s'", table_key->name)); } /*end of for (; table_key < table_key_end;) */ @@ -5504,6 +5538,8 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, } if (drop) { + if (table->s->tmp_table == NO_TMP_TABLE) + (void) delete_statistics_for_column(thd, table, field); drop_it.remove(); /* ALTER TABLE DROP COLUMN always changes table data even in cases @@ -5656,12 +5692,15 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, } if (drop) { + if (table->s->tmp_table == NO_TMP_TABLE) + (void) delete_statistics_for_index(thd, table, key_info); drop_it.remove(); continue; } KEY_PART_INFO *key_part= key_info->key_part; key_parts.empty(); + bool delete_index_stat= FALSE; for (uint j=0 ; j < key_info->key_parts ; j++,key_part++) { if (!key_part->field) @@ -5684,7 +5723,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, break; } if (!cfield) + { + delete_index_stat= TRUE; continue; // Field is removed + } key_part_length= key_part->length; if (cfield->field) // Not new field { @@ -5726,6 +5768,8 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, strlen(cfield->field_name), key_part_length)); } + if (delete_index_stat && table->s->tmp_table == NO_TMP_TABLE) + (void) delete_statistics_for_index(thd, table, key_info); if (key_parts.elements) { KEY_CREATE_INFO key_create_info; @@ -5905,6 +5949,9 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, enum ha_extra_function extra_func= thd->locked_tables_mode ? HA_EXTRA_NOT_USED : HA_EXTRA_FORCE_REOPEN; + LEX_STRING old_db_name= { table_list->db, table_list->db_length }; + LEX_STRING old_table_name= { table_list->table_name, + table_list->table_name_length }; DBUG_ENTER("mysql_alter_table"); /* @@ -6209,6 +6256,12 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, else { *fn_ext(new_name)=0; + + LEX_STRING new_db_name= { new_db, strlen(new_db) }; + LEX_STRING new_table_name= { new_alias, strlen(new_alias) }; + (void) rename_table_in_stat_tables(thd, &old_db_name, &old_table_name, + &new_db_name, &new_table_name); + if (mysql_rename_table(old_db_type,db,table_name,new_db,new_alias, 0)) error= -1; else if (Table_triggers_list::change_table_name(thd, db, @@ -6920,6 +6973,15 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, table is renamed and the SE is also changed, then an intermediate table is created and the additional call will not take place. */ + + if (new_name != table_name || new_db != db) + { + LEX_STRING new_db_name= { new_db, strlen(new_db) }; + LEX_STRING new_table_name= { new_name, strlen(new_name) }; + (void) rename_table_in_stat_tables(thd, &old_db_name, &old_table_name, + &new_db_name, &new_table_name); + } + if (need_copy_table == ALTER_TABLE_METADATA_ONLY) { DBUG_ASSERT(new_db_type == old_db_type); From cb0a5c84b63a24d143160e38995cb35268f8eef4 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 10 Jul 2012 22:12:23 -0700 Subject: [PATCH 18/35] Made the output of the newly added test cases from statistics.test platform independent. Adjusted results of funcs_1.is_columns_mysql_embedded. --- mysql-test/r/statistics.result | 80 +++++++++++-------- .../r/is_columns_mysql_embedded.result | 18 ++--- mysql-test/t/statistics.test | 22 +++-- 3 files changed, 70 insertions(+), 50 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index a4e60e266d0..680712e5f4a 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -1159,42 +1159,52 @@ WORLD_INNODB COUNTRYLANGUAGE PRIMARY 2 1.0000 WORLD_INNODB COUNTRYLANGUAGE Percentage 1 2.7640 use test; DROP DATABASE world; -SELECT * FROM mysql.table_stat; -db_name table_name cardinality -world_innodb Country 239 -world_innodb City 4079 -world_innodb CountryLanguage 984 -SELECT * FROM mysql.column_stat; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -world_innodb Country Code ABW ZWE 0.0000 3.0000 1.0000 -world_innodb Country Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 -world_innodb Country SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 -world_innodb Country Population 0 1277558000 0.0000 4.0000 1.0575 -world_innodb Country Capital 1 4074 0.0293 4.0000 1.0000 -world_innodb City ID 1 4079 0.0000 4.0000 1.0000 -world_innodb City Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 -world_innodb City Country ABW ZWE 0.0000 3.0000 17.5819 -world_innodb City Population 42 10500000 0.0000 4.0000 1.0467 -world_innodb CountryLanguage Country ABW ZWE 0.0000 3.0000 4.2232 -world_innodb CountryLanguage Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 -world_innodb CountryLanguage Percentage 0.0 99.9 0.0000 4.0000 2.7640 -SELECT * FROM mysql.index_stat; -db_name table_name index_name prefix_arity avg_frequency -world_innodb Country PRIMARY 1 1.0000 -world_innodb Country Name 1 1.0000 -world_innodb City PRIMARY 1 1.0000 -world_innodb City Population 1 1.0467 -world_innodb City Country 1 17.5819 -world_innodb CountryLanguage PRIMARY 1 4.2232 -world_innodb CountryLanguage PRIMARY 2 1.0000 -world_innodb CountryLanguage Percentage 1 2.7640 +SELECT UPPER(db_name), UPPER(table_name), cardinality +FROM mysql.table_stat; +UPPER(db_name) UPPER(table_name) cardinality +WORLD_INNODB COUNTRY 239 +WORLD_INNODB CITY 4079 +WORLD_INNODB COUNTRYLANGUAGE 984 +SELECT UPPER(db_name), UPPER(table_name), +column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency +FROM mysql.column_stat; +UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency +WORLD_INNODB COUNTRY Code ABW ZWE 0.0000 3.0000 1.0000 +WORLD_INNODB COUNTRY Name Afghanistan Zimbabwe 0.0000 10.1088 1.0000 +WORLD_INNODB COUNTRY SurfaceArea 0.40 17075400.00 0.0000 4.0000 1.0042 +WORLD_INNODB COUNTRY Population 0 1277558000 0.0000 4.0000 1.0575 +WORLD_INNODB COUNTRY Capital 1 4074 0.0293 4.0000 1.0000 +WORLD_INNODB CITY ID 1 4079 0.0000 4.0000 1.0000 +WORLD_INNODB CITY Name A Coruña (La Coruña) Ürgenc 0.0000 8.6416 1.0195 +WORLD_INNODB CITY Country ABW ZWE 0.0000 3.0000 17.5819 +WORLD_INNODB CITY Population 42 10500000 0.0000 4.0000 1.0467 +WORLD_INNODB COUNTRYLANGUAGE Country ABW ZWE 0.0000 3.0000 4.2232 +WORLD_INNODB COUNTRYLANGUAGE Language Abhyasi [South]Mande 0.0000 7.1778 2.1532 +WORLD_INNODB COUNTRYLANGUAGE Percentage 0.0 99.9 0.0000 4.0000 2.7640 +SELECT UPPER(db_name), UPPER(table_name), +index_name, prefix_arity, avg_frequency +FROM mysql.index_stat; +UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency +WORLD_INNODB COUNTRY PRIMARY 1 1.0000 +WORLD_INNODB COUNTRY Name 1 1.0000 +WORLD_INNODB CITY PRIMARY 1 1.0000 +WORLD_INNODB CITY Population 1 1.0467 +WORLD_INNODB CITY Country 1 17.5819 +WORLD_INNODB COUNTRYLANGUAGE PRIMARY 1 4.2232 +WORLD_INNODB COUNTRYLANGUAGE PRIMARY 2 1.0000 +WORLD_INNODB COUNTRYLANGUAGE Percentage 1 2.7640 DROP DATABASE world_innodb; -SELECT * FROM mysql.table_stat; -db_name table_name cardinality -SELECT * FROM mysql.column_stat; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -SELECT * FROM mysql.index_stat; -db_name table_name index_name prefix_arity avg_frequency +SELECT UPPER(db_name), UPPER(table_name), cardinality +FROM mysql.table_stat; +UPPER(db_name) UPPER(table_name) cardinality +SELECT UPPER(db_name), UPPER(table_name), +column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency +FROM mysql.column_stat; +UPPER(db_name) UPPER(table_name) column_name min_value max_value nulls_ratio avg_length avg_frequency +SELECT UPPER(db_name), UPPER(table_name), +index_name, prefix_arity, avg_frequency +FROM mysql.index_stat; +UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; diff --git a/mysql-test/suite/funcs_1/r/is_columns_mysql_embedded.result b/mysql-test/suite/funcs_1/r/is_columns_mysql_embedded.result index 031d9660e5b..38a4b9b69c6 100644 --- a/mysql-test/suite/funcs_1/r/is_columns_mysql_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_columns_mysql_embedded.result @@ -9,13 +9,13 @@ def mysql columns_priv Host 1 NO char 60 180 NULL NULL NULL utf8 utf8_bin char( def mysql columns_priv Table_name 4 NO char 64 192 NULL NULL NULL utf8 utf8_bin char(64) PRI def mysql columns_priv Timestamp 6 CURRENT_TIMESTAMP NO timestamp NULL NULL NULL NULL 0 NULL NULL timestamp on update CURRENT_TIMESTAMP def mysql columns_priv User 3 NO char 16 48 NULL NULL NULL utf8 utf8_bin char(16) PRI -def mysql column_stat avg_frequency 8 NULL YES double NULL NULL 22 NULL NULL NULL NULL double -def mysql column_stat avg_length 7 NULL YES double NULL NULL 22 NULL NULL NULL NULL double +def mysql column_stat avg_frequency 8 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) +def mysql column_stat avg_length 7 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) def mysql column_stat column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql column_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql column_stat max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) def mysql column_stat min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) -def mysql column_stat nulls_ratio 6 NULL YES double NULL NULL 22 NULL NULL NULL NULL double +def mysql column_stat nulls_ratio 6 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) def mysql column_stat table_name 2 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql db Alter_priv 13 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') def mysql db Alter_routine_priv 19 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') @@ -105,7 +105,7 @@ def mysql host Select_priv 3 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci e def mysql host Show_view_priv 16 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') def mysql host Trigger_priv 20 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') def mysql host Update_priv 5 N NO enum 1 3 NULL NULL NULL utf8 utf8_general_ci enum('N','Y') -def mysql index_stat avg_frequency 5 NULL YES double NULL NULL 22 NULL NULL NULL NULL double +def mysql index_stat avg_frequency 5 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) def mysql index_stat db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql index_stat index_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql index_stat prefix_arity 4 NULL NO int NULL NULL 10 0 NULL NULL NULL int(11) unsigned PRI @@ -291,7 +291,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME NULL bigint NULL NULL NULL datetime NULL NULL -NULL double NULL NULL +NULL decimal NULL NULL NULL int NULL NULL NULL smallint NULL NULL NULL time NULL NULL @@ -325,9 +325,9 @@ NULL mysql columns_priv Timestamp timestamp NULL NULL NULL NULL timestamp 3.0000 mysql column_stat column_name varchar 64 192 utf8 utf8_bin varchar(64) 3.0000 mysql column_stat min_value varchar 255 765 utf8 utf8_bin varchar(255) 3.0000 mysql column_stat max_value varchar 255 765 utf8 utf8_bin varchar(255) -NULL mysql column_stat nulls_ratio double NULL NULL NULL NULL double -NULL mysql column_stat avg_length double NULL NULL NULL NULL double -NULL mysql column_stat avg_frequency double NULL NULL NULL NULL double +NULL mysql column_stat nulls_ratio decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stat avg_length decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stat avg_frequency decimal NULL NULL NULL NULL decimal(12,4) 3.0000 mysql db Host char 60 180 utf8 utf8_bin char(60) 3.0000 mysql db Db char 64 192 utf8 utf8_bin char(64) 3.0000 mysql db User char 16 48 utf8 utf8_bin char(16) @@ -420,7 +420,7 @@ NULL mysql help_topic help_category_id smallint NULL NULL NULL NULL smallint(5) 3.0000 mysql index_stat table_name varchar 64 192 utf8 utf8_bin varchar(64) 3.0000 mysql index_stat index_name varchar 64 192 utf8 utf8_bin varchar(64) NULL mysql index_stat prefix_arity int NULL NULL NULL NULL int(11) unsigned -NULL mysql index_stat avg_frequency double NULL NULL NULL NULL double +NULL mysql index_stat avg_frequency decimal NULL NULL NULL NULL decimal(12,4) NULL mysql ndb_binlog_index Position bigint NULL NULL NULL NULL bigint(20) unsigned 1.0000 mysql ndb_binlog_index File varchar 255 255 latin1 latin1_swedish_ci varchar(255) NULL mysql ndb_binlog_index epoch bigint NULL NULL NULL NULL bigint(20) unsigned diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 0427c82349c..903cf27648c 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -471,14 +471,24 @@ SELECT UPPER(db_name), UPPER(table_name), use test; DROP DATABASE world; -SELECT * FROM mysql.table_stat; -SELECT * FROM mysql.column_stat; -SELECT * FROM mysql.index_stat; +SELECT UPPER(db_name), UPPER(table_name), cardinality + FROM mysql.table_stat; +SELECT UPPER(db_name), UPPER(table_name), + column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency + FROM mysql.column_stat; +SELECT UPPER(db_name), UPPER(table_name), + index_name, prefix_arity, avg_frequency + FROM mysql.index_stat; DROP DATABASE world_innodb; -SELECT * FROM mysql.table_stat; -SELECT * FROM mysql.column_stat; -SELECT * FROM mysql.index_stat; +SELECT UPPER(db_name), UPPER(table_name), cardinality + FROM mysql.table_stat; +SELECT UPPER(db_name), UPPER(table_name), + column_name, min_value, max_value, nulls_ratio, avg_length, avg_frequency + FROM mysql.column_stat; +SELECT UPPER(db_name), UPPER(table_name), + index_name, prefix_arity, avg_frequency + FROM mysql.index_stat; DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; From 8c499274da21af6226785d51dd24968bf2b1befe Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 26 Jul 2012 17:50:08 -0700 Subject: [PATCH 19/35] Performed re-factoring and re-structuring of the code for mwl#248: - Moved the definitions of the classes to store data from persistent statistical tables into statistics.h, leaving in other internal data structures only references to the corresponding objects. - Defined class Column_statistics_collected derived from the class Column_statistics. This is a helper class to collect statistics on columns. - Moved references to read statistics to TABLE SHARE, leaving the the reference to the collected statistics in TABLE. - Added a new clone method for the class Field allowing to clone fields attached to table shares. It was was used to create fields for min/max values in the memory of the table share. A lso: - Added procedures to allocate memory for statistical data in the table share memory and in table memory. Also: - Added a test case demonstrating how ANALYZE could work in parallel to collect statistics on different indexes of the same table. - Added a test two demonstrate how two connections working simultaneously could allocate memory for statistical data in the table share memory. --- mysql-test/r/stat_tables.result | 116 ++++ mysql-test/r/stat_tables_innodb.result | 172 ++++++ mysql-test/t/stat_tables.test | 109 ++++ sql/field.cc | 137 +++-- sql/field.h | 83 +-- sql/mysqld.cc | 3 + sql/sql_admin.cc | 2 + sql/sql_base.cc | 28 +- sql/sql_base.h | 3 + sql/sql_select.cc | 9 +- sql/sql_statistics.cc | 743 +++++++++++++++++-------- sql/sql_statistics.h | 155 ++++++ sql/structs.h | 41 +- sql/table.cc | 30 +- sql/table.h | 25 +- 15 files changed, 1223 insertions(+), 433 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 26f2b602c6b..09486d4ce0b 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -334,6 +334,122 @@ and o_orderkey=l_orderkey and p_partkey=l_partkey; o_orderkey p_partkey 5895 200 set optimizer_switch=@save_optimizer_switch; +flush table lineitem; +set use_stat_tables='never'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24 ; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +revenue +77949.91860000002 +set use_stat_tables='preferably'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +delete from mysql.index_stat +where table_name='lineitem' and +index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +delete from mysql.index_stat +where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 DROP DATABASE dbt3_s001; use test; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 3d534dcab29..4cb1261b689 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -361,6 +361,178 @@ and o_orderkey=l_orderkey and p_partkey=l_partkey; o_orderkey p_partkey 5895 200 set optimizer_switch=@save_optimizer_switch; +flush table lineitem; +set use_stat_tables='never'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24 ; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +revenue +77949.91860000002 +set use_stat_tables='preferably'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_receiptdate 3 1.0000 +dbt3_s001 lineitem i_l_receiptdate 2 1.0152 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_shipdate 3 1.0000 +dbt3_s001 lineitem i_l_shipdate 2 1.0149 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +delete from mysql.index_stat +where table_name='lineitem' and +index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_shipdate 3 1.0000 +dbt3_s001 lineitem i_l_shipdate 2 1.0149 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 +delete from mysql.index_stat +where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 2 1.0364 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_commitdate 3 1.0000 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey 2 1.0000 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 +dbt3_s001 lineitem i_l_partkey 3 1.0000 +dbt3_s001 lineitem i_l_partkey 2 1.0089 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 3 1.0000 +dbt3_s001 lineitem i_l_suppkey 2 1.2073 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 DROP DATABASE dbt3_s001; use test; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 640f9febc75..bdb689228b2 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -144,6 +144,115 @@ eval $QQ1; set optimizer_switch=@save_optimizer_switch; +# +# Test for parallel memory allocation for statistical data +# +# assumes that start the code of memory allocation for stats data has this line: +# +# DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); +# DEBUG_SYNC(thd, "statistics_mem_alloc-start2"); +# + +let $Q6= +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' + and l_shipdate < date '1994-01-01' + interval '1' year + and l_discount between 0.06 - 0.01 and 0.06 + 0.01 + and l_quantity < 24; + +flush table lineitem; +set use_stat_tables='never'; +eval $Q6; + +connect (con1, localhost, root,,); +connect (con2, localhost, root,,); + +connection con1; +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send_eval $Q6 + +connection con2; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send_eval $Q6 + +connection con1; +--reap + +connection con2; +--reap + +connection default; +set use_stat_tables='preferably'; +disconnect con1; +disconnect con2; + +# +# Test for parallel statistics collection +# +# assumes that start of stats collection code has this line: +# +# DEBUG_SYNC(thd, "statistics_collection_start1"); +# DEBUG_SYNC(thd, "statistics_collection_start2"); +# + +select * from mysql.index_stat where table_name='lineitem' order by index_name; +delete from mysql.index_stat + where table_name='lineitem' and + index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +--disable_result_log +--disable_warnings +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +--enable_warnings +--enable_result_log +select * from mysql.index_stat where table_name='lineitem' order by index_name; +delete from mysql.index_stat + where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; + +connect (con1, localhost, root,,); +connect (con2, localhost, root,,); + +connection con1; +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send analyze table lineitem persistent for columns() indexes (i_l_shipdate) + +connection con2; +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send analyze table lineitem persistent for columns() indexes (i_l_receiptdate) + +connection con1; +--disable_result_log +--disable_warnings +--reap +--enable_warnings +--enable_result_log + +connection con2; +--disable_result_log +--disable_warnings +--reap +--enable_warnings +--enable_result_log + +connection default; +disconnect con1; +disconnect con2; + +select * from mysql.index_stat where table_name='lineitem' order by index_name; DROP DATABASE dbt3_s001; diff --git a/sql/field.cc b/sql/field.cc index d37679451fc..406128ba484 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -1180,11 +1180,11 @@ int Field_num::check_int(CHARSET_INFO *cs, const char *str, int length, if (str == int_end || error == MY_ERRNO_EDOM) { ErrConvString err(str, length, cs); - push_warning_printf(table->in_use, MYSQL_ERROR::WARN_LEVEL_WARN, + push_warning_printf(get_thd(), MYSQL_ERROR::WARN_LEVEL_WARN, ER_TRUNCATED_WRONG_VALUE_FOR_FIELD, ER(ER_TRUNCATED_WRONG_VALUE_FOR_FIELD), "integer", err.ptr(), field_name, - (ulong) table->in_use->warning_info->current_row_for_warning()); + (ulong) get_thd()->warning_info->current_row_for_warning()); return 1; } /* Test if we have garbage at the end of the given string. */ @@ -1253,7 +1253,7 @@ bool Field_num::get_int(CHARSET_INFO *cs, const char *from, uint len, goto out_of_range; } } - if (table->in_use->count_cuted_fields && + if (get_thd()->count_cuted_fields && check_int(cs, from, len, end, error)) return 1; return 0; @@ -1319,12 +1319,14 @@ String *Field::val_int_as_str(String *val_buffer, bool unsigned_val) Field::Field(uchar *ptr_arg,uint32 length_arg,uchar *null_ptr_arg, uchar null_bit_arg, utype unireg_check_arg, const char *field_name_arg) - :ptr(ptr_arg), null_ptr(null_ptr_arg), table(0), orig_table(0), + :ptr(ptr_arg), null_ptr(null_ptr_arg), table(0), orig_table(0), thd(0), table_name(0), field_name(field_name_arg), option_list(0), option_struct(0), key_start(0), part_of_key(0), part_of_key_not_clustered(0), part_of_sortkey(0), unireg_check(unireg_check_arg), field_length(length_arg), - null_bit(null_bit_arg), is_created_from_null_item(FALSE), vcol_info(0), + null_bit(null_bit_arg), is_created_from_null_item(FALSE), + read_stats(NULL), collected_stats(0), + vcol_info(0), stored_in_db(TRUE) { flags=null_ptr ? 0: NOT_NULL_FLAG; @@ -1431,10 +1433,11 @@ int Field::store(const char *to, uint length, CHARSET_INFO *cs, enum_check_fields check_level) { int res; - enum_check_fields old_check_level= table->in_use->count_cuted_fields; - table->in_use->count_cuted_fields= check_level; + THD *thd= get_thd(); + enum_check_fields old_check_level= thd->count_cuted_fields; + thd->count_cuted_fields= check_level; res= store(to, length, cs); - table->in_use->count_cuted_fields= old_check_level; + thd->count_cuted_fields= old_check_level; return res; } @@ -1871,6 +1874,18 @@ Field *Field::clone(MEM_ROOT *root, TABLE *new_table, my_ptrdiff_t diff, } +Field *Field::clone(THD *thd_arg, MEM_ROOT *root, my_ptrdiff_t diff) +{ + Field *tmp; + if ((tmp= (Field*) memdup_root(root,(char*) this,size_of()))) + { + tmp->thd= thd_arg; + tmp->move_field_offset(diff); + } + return tmp; +} + + /**************************************************************************** Field_null, a field that always return NULL ****************************************************************************/ @@ -1985,7 +2000,7 @@ int Field_decimal::store(const char *from_arg, uint len, CHARSET_INFO *cs) uchar *left_wall,*right_wall; uchar tmp_char; /* - To remember if table->in_use->cuted_fields has already been incremented, + To remember if get_thd()->cuted_fields has already been incremented, to do that only once */ bool is_cuted_fields_incr=0; @@ -2076,7 +2091,7 @@ int Field_decimal::store(const char *from_arg, uint len, CHARSET_INFO *cs) it makes the code easer to read. */ - if (table->in_use->count_cuted_fields) + if (get_thd()->count_cuted_fields) { // Skip end spaces for (;from != end && my_isspace(&my_charset_bin, *from); from++) ; @@ -2228,7 +2243,7 @@ int Field_decimal::store(const char *from_arg, uint len, CHARSET_INFO *cs) /* Write digits of the frac_% parts ; - Depending on table->in_use->count_cutted_fields, we may also want + Depending on get_thd()->count_cutted_fields, we may also want to know if some non-zero tail of these parts will be truncated (for example, 0.002->0.00 will generate a warning, while 0.000->0.00 will not) @@ -2246,7 +2261,7 @@ int Field_decimal::store(const char *from_arg, uint len, CHARSET_INFO *cs) { if (pos == right_wall) { - if (table->in_use->count_cuted_fields && !is_cuted_fields_incr) + if (get_thd()->count_cuted_fields && !is_cuted_fields_incr) break; // Go on below to see if we lose non zero digits return 0; } @@ -2667,20 +2682,21 @@ int Field_new_decimal::store(const char *from, uint length, ASSERT_COLUMN_MARKED_FOR_WRITE_OR_COMPUTED; int err; my_decimal decimal_value; + THD *thd= get_thd(); DBUG_ENTER("Field_new_decimal::store(char*)"); if ((err= str2my_decimal(E_DEC_FATAL_ERROR & ~(E_DEC_OVERFLOW | E_DEC_BAD_NUM), from, length, charset_arg, &decimal_value)) && - table->in_use->abort_on_warning) + thd->abort_on_warning) { ErrConvString errmsg(from, length, &my_charset_bin); - push_warning_printf(table->in_use, MYSQL_ERROR::WARN_LEVEL_WARN, + push_warning_printf(thd, MYSQL_ERROR::WARN_LEVEL_WARN, ER_TRUNCATED_WRONG_VALUE_FOR_FIELD, ER(ER_TRUNCATED_WRONG_VALUE_FOR_FIELD), "decimal", errmsg.ptr(), field_name, - (ulong) table->in_use->warning_info->current_row_for_warning()); + (ulong) thd->warning_info->current_row_for_warning()); DBUG_RETURN(err); } @@ -2696,11 +2712,11 @@ int Field_new_decimal::store(const char *from, uint length, case E_DEC_BAD_NUM: { ErrConvString errmsg(from, length, &my_charset_bin); - push_warning_printf(table->in_use, MYSQL_ERROR::WARN_LEVEL_WARN, + push_warning_printf(thd, MYSQL_ERROR::WARN_LEVEL_WARN, ER_TRUNCATED_WRONG_VALUE_FOR_FIELD, ER(ER_TRUNCATED_WRONG_VALUE_FOR_FIELD), "decimal", errmsg.ptr(), field_name, - (ulong) table->in_use->warning_info-> + (ulong) thd->warning_info-> current_row_for_warning()); my_decimal_set_zero(&decimal_value); break; @@ -2728,6 +2744,7 @@ int Field_new_decimal::store(double nr) ASSERT_COLUMN_MARKED_FOR_WRITE_OR_COMPUTED; my_decimal decimal_value; int err; + THD *thd= get_thd(); DBUG_ENTER("Field_new_decimal::store(double)"); err= double2my_decimal(E_DEC_FATAL_ERROR & ~E_DEC_OVERFLOW, nr, @@ -2737,11 +2754,11 @@ int Field_new_decimal::store(double nr) if (check_overflow(err)) set_value_on_overflow(&decimal_value, decimal_value.sign()); /* Only issue a warning if store_value doesn't issue an warning */ - table->in_use->got_warning= 0; + thd->got_warning= 0; } if (store_value(&decimal_value)) err= 1; - else if (err && !table->in_use->got_warning) + else if (err && !thd->got_warning) err= warn_if_overflow(err); DBUG_RETURN(err); } @@ -2759,11 +2776,11 @@ int Field_new_decimal::store(longlong nr, bool unsigned_val) if (check_overflow(err)) set_value_on_overflow(&decimal_value, decimal_value.sign()); /* Only issue a warning if store_value doesn't issue an warning */ - table->in_use->got_warning= 0; + get_thd()->got_warning= 0; } if (store_value(&decimal_value)) err= 1; - else if (err && !table->in_use->got_warning) + else if (err && !thd->got_warning) err= warn_if_overflow(err); return err; } @@ -3659,7 +3676,7 @@ longlong Field_long::val_int(void) ASSERT_COLUMN_MARKED_FOR_READ; int32 j; /* See the comment in Field_long::store(long long) */ - DBUG_ASSERT(table->in_use == current_thd); + DBUG_ASSERT(!table || table->in_use == current_thd); j=sint4korr(ptr); return unsigned_flag ? (longlong) (uint32) j : (longlong) j; } @@ -3741,7 +3758,7 @@ int Field_longlong::store(const char *from,uint len,CHARSET_INFO *cs) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_WARN_DATA_OUT_OF_RANGE, 1); error= 1; } - else if (table->in_use->count_cuted_fields && + else if (get_thd()->count_cuted_fields && check_int(cs, from, len, end, error)) error= 1; else @@ -3893,7 +3910,7 @@ int Field_float::store(const char *from,uint len,CHARSET_INFO *cs) char *end; double nr= my_strntod(cs,(char*) from,len,&end,&error); if (error || (!len || ((uint) (end-from) != len && - table->in_use->count_cuted_fields))) + get_thd()->count_cuted_fields))) { set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, (error ? ER_WARN_DATA_OUT_OF_RANGE : WARN_DATA_TRUNCATED), 1); @@ -4081,7 +4098,7 @@ int Field_double::store(const char *from,uint len,CHARSET_INFO *cs) char *end; double nr= my_strntod(cs,(char*) from, len, &end, &error); if (error || (!len || ((uint) (end-from) != len && - table->in_use->count_cuted_fields))) + get_thd()->count_cuted_fields))) { set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, (error ? ER_WARN_DATA_OUT_OF_RANGE : WARN_DATA_TRUNCATED), 1); @@ -4529,10 +4546,11 @@ int Field_timestamp::store_TIME_with_warning(THD *thd, MYSQL_TIME *l_time, int Field_timestamp::store_time_dec(MYSQL_TIME *ltime, uint dec) { - THD *thd= table->in_use; int unused; MYSQL_TIME l_time= *ltime; ErrConvTime str(ltime); + THD *thd= get_thd(); + bool valid= !check_date(&l_time, pack_time(&l_time) != 0, (thd->variables.sql_mode & MODE_NO_ZERO_DATE) | MODE_NO_ZERO_IN_DATE, &unused); @@ -4547,7 +4565,7 @@ int Field_timestamp::store(const char *from,uint len,CHARSET_INFO *cs) int error; int have_smth_to_conv; ErrConvString str(from, len, cs); - THD *thd= table->in_use; + THD *thd= get_thd(); /* We don't want to store invalid or fuzzy datetime values in TIMESTAMP */ have_smth_to_conv= (str_to_datetime(cs, from, len, &l_time, @@ -4564,7 +4582,7 @@ int Field_timestamp::store(double nr) MYSQL_TIME l_time; int error; ErrConvDouble str(nr); - THD *thd= table->in_use; + THD *thd= get_thd(); longlong tmp= double_to_datetime(nr, &l_time, (thd->variables.sql_mode & MODE_NO_ZERO_DATE) | @@ -4578,7 +4596,7 @@ int Field_timestamp::store(longlong nr, bool unsigned_val) MYSQL_TIME l_time; int error; ErrConvInteger str(nr); - THD *thd= table->in_use; + THD *thd= get_thd(); /* We don't want to store invalid or fuzzy datetime values in TIMESTAMP */ longlong tmp= number_to_datetime(nr, 0, &l_time, (thd->variables.sql_mode & @@ -4670,7 +4688,7 @@ String *Field_timestamp::val_str(String *val_buffer, String *val_ptr) bool Field_timestamp::get_date(MYSQL_TIME *ltime, ulonglong fuzzydate) { - THD *thd= table->in_use; + THD *thd= get_thd(); thd->time_zone_used= 1; ulong sec_part; my_time_t temp= get_timestamp(&sec_part); @@ -4723,7 +4741,7 @@ void Field_timestamp::sql_type(String &res) const int Field_timestamp::set_time() { - THD *thd= table->in_use; + THD *thd= get_thd(); set_notnull(); store_TIME(thd->query_start(), 0); return 0; @@ -4872,7 +4890,7 @@ int Field_timestamp_hires::store_decimal(const my_decimal *d) int error; MYSQL_TIME ltime; longlong tmp; - THD *thd= table->in_use; + THD *thd= get_thd(); ErrConvDecimal str(d); if (my_decimal2seconds(d, &nr, &sec_part)) @@ -4890,7 +4908,7 @@ int Field_timestamp_hires::store_decimal(const my_decimal *d) int Field_timestamp_hires::set_time() { - THD *thd= table->in_use; + THD *thd= get_thd(); set_notnull(); store_TIME(thd->query_start(), thd->query_start_sec_part()); return 0; @@ -5009,7 +5027,7 @@ int Field_temporal::store(const char *from,uint len,CHARSET_INFO *cs) MYSQL_TIME ltime; int error; enum enum_mysql_timestamp_type func_res; - THD *thd= table->in_use; + THD *thd= get_thd(); ErrConvString str(from, len, cs); func_res= str_to_datetime(cs, from, len, <ime, @@ -5026,7 +5044,7 @@ int Field_temporal::store(double nr) { int error= 0; MYSQL_TIME ltime; - THD *thd= table->in_use; + THD *thd= get_thd(); ErrConvDouble str(nr); longlong tmp= double_to_datetime(nr, <ime, @@ -5044,7 +5062,7 @@ int Field_temporal::store(longlong nr, bool unsigned_val) int error; MYSQL_TIME ltime; longlong tmp; - THD *thd= table->in_use; + THD *thd= get_thd(); ErrConvInteger str(nr); tmp= number_to_datetime(nr, 0, <ime, (TIME_FUZZY_DATE | @@ -5109,7 +5127,7 @@ int Field_time::store(const char *from,uint len,CHARSET_INFO *cs) int was_cut; int have_smth_to_conv= str_to_time(cs, from, len, <ime, - table->in_use->variables.sql_mode & + get_thd()->variables.sql_mode & (MODE_NO_ZERO_DATE | MODE_NO_ZERO_IN_DATE | MODE_INVALID_DATES), &was_cut) > MYSQL_TIMESTAMP_ERROR; @@ -5215,7 +5233,7 @@ String *Field_time::val_str(String *val_buffer, bool Field_time::get_date(MYSQL_TIME *ltime, ulonglong fuzzydate) { - THD *thd= table->in_use; + THD *thd= get_thd(); if (!(fuzzydate & (TIME_FUZZY_DATE|TIME_TIME_ONLY))) { push_warning_printf(thd, MYSQL_ERROR::WARN_LEVEL_WARN, @@ -5405,7 +5423,7 @@ int Field_year::store(const char *from, uint len,CHARSET_INFO *cs) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_WARN_DATA_OUT_OF_RANGE, 1); return 1; } - if (table->in_use->count_cuted_fields && + if (get_thd()->count_cuted_fields && (error= check_int(cs, from, len, end, error))) { if (error == 1) /* empty or incorrect string */ @@ -5865,7 +5883,7 @@ int Field_datetime_hires::store_decimal(const my_decimal *d) int error; MYSQL_TIME ltime; longlong tmp; - THD *thd= table->in_use; + THD *thd= get_thd(); ErrConvDecimal str(d); if (my_decimal2seconds(d, &nr, &sec_part)) @@ -6002,7 +6020,9 @@ check_string_copy_error(Field_str *field, { const char *pos; char tmp[32]; - THD *thd= field->table->in_use; + THD *thd; + + thd= field->get_thd(); if (!(pos= well_formed_error_pos) && !(pos= cannot_convert_error_pos)) @@ -6044,11 +6064,12 @@ int Field_longstr::report_if_important_data(const char *pstr, const char *end, bool count_spaces) { - if ((pstr < end) && table->in_use->count_cuted_fields) + THD *thd= get_thd(); + if ((pstr < end) && thd->count_cuted_fields) { if (test_if_important_data(field_charset, pstr, end)) { - if (table->in_use->abort_on_warning) + if (thd->abort_on_warning) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_DATA_TOO_LONG, 1); else set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, WARN_DATA_TRUNCATED, 1); @@ -6075,7 +6096,7 @@ int Field_string::store(const char *from,uint length,CHARSET_INFO *cs) const char *from_end_pos; /* See the comment for Field_long::store(long long) */ - DBUG_ASSERT(table->in_use == current_thd); + DBUG_ASSERT(!table || table->in_use == current_thd); copy_length= well_formed_copy_nchars(field_charset, (char*) ptr, field_length, @@ -6121,7 +6142,7 @@ int Field_str::store(double nr) if (error) { - if (table->in_use->abort_on_warning) + if (get_thd()->abort_on_warning) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_DATA_TOO_LONG, 1); else set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, WARN_DATA_TRUNCATED, 1); @@ -6181,7 +6202,7 @@ double Field_string::val_real(void) double result; result= my_strntod(cs,(char*) ptr,field_length,&end,&error); - if (!table->in_use->no_errors && + if (!get_thd()->no_errors && (error || (field_length != (uint32)(end - (char*) ptr) && !check_if_only_end_space(cs, end, (char*) ptr + field_length)))) @@ -6205,7 +6226,7 @@ longlong Field_string::val_int(void) longlong result; result= my_strntoll(cs, (char*) ptr,field_length,10,&end,&error); - if (!table->in_use->no_errors && + if (!get_thd()->no_errors && (error || (field_length != (uint32)(end - (char*) ptr) && !check_if_only_end_space(cs, end, (char*) ptr + field_length)))) @@ -6225,9 +6246,9 @@ String *Field_string::val_str(String *val_buffer __attribute__((unused)), { ASSERT_COLUMN_MARKED_FOR_READ; /* See the comment for Field_long::store(long long) */ - DBUG_ASSERT(table->in_use == current_thd); + DBUG_ASSERT(!table || table->in_use == current_thd); uint length; - if (table->in_use->variables.sql_mode & + if (get_thd()->variables.sql_mode & MODE_PAD_CHAR_TO_FULL_LENGTH) length= my_charpos(field_charset, ptr, ptr + field_length, field_length / field_charset->mbmaxlen); @@ -6244,7 +6265,7 @@ my_decimal *Field_string::val_decimal(my_decimal *decimal_value) ASSERT_COLUMN_MARKED_FOR_READ; int err= str2my_decimal(E_DEC_FATAL_ERROR, (char*) ptr, field_length, charset(), decimal_value); - if (!table->in_use->no_errors && err) + if (!get_thd()->no_errors && err) { ErrConvString errmsg((char*) ptr, field_length, charset()); push_warning_printf(current_thd, MYSQL_ERROR::WARN_LEVEL_WARN, @@ -6628,7 +6649,7 @@ double Field_varstring::val_real(void) uint length= length_bytes == 1 ? (uint) *ptr : uint2korr(ptr); result= my_strntod(cs, (char*)ptr+length_bytes, length, &end, &error); - if (!table->in_use->no_errors && + if (!get_thd()->no_errors && (error || (length != (uint)(end - (char*)ptr+length_bytes) && !check_if_only_end_space(cs, end, (char*)ptr+length_bytes+length)))) { @@ -6651,7 +6672,7 @@ longlong Field_varstring::val_int(void) longlong result= my_strntoll(cs, (char*) ptr+length_bytes, length, 10, &end, &error); - if (!table->in_use->no_errors && + if (!get_thd()->no_errors && (error || (length != (uint)(end - (char*)ptr+length_bytes) && !check_if_only_end_space(cs, end, (char*)ptr+length_bytes+length)))) { @@ -6680,7 +6701,7 @@ my_decimal *Field_varstring::val_decimal(my_decimal *decimal_value) int error= str2my_decimal(E_DEC_FATAL_ERROR, (char*) ptr+length_bytes, length, cs, decimal_value); - if (!table->in_use->no_errors && error) + if (!get_thd()->no_errors && error) { push_numerical_conversion_warning(current_thd, (char*)ptr+length_bytes, length, cs, "DECIMAL", @@ -7661,7 +7682,7 @@ int Field_enum::store(const char *from,uint length,CHARSET_INFO *cs) tmp=0; set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, WARN_DATA_TRUNCATED, 1); } - if (!table->in_use->count_cuted_fields) + if (!get_thd()->count_cuted_fields) err= 0; } else @@ -7685,7 +7706,7 @@ int Field_enum::store(longlong nr, bool unsigned_val) if ((ulonglong) nr > typelib->count || nr == 0) { set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, WARN_DATA_TRUNCATED, 1); - if (nr != 0 || table->in_use->count_cuted_fields) + if (nr != 0 || get_thd()->count_cuted_fields) { nr= 0; error= 1; @@ -8215,7 +8236,7 @@ int Field_bit::store(const char *from, uint length, CHARSET_INFO *cs) { set_rec_bits((1 << bit_len) - 1, bit_ptr, bit_ofs, bit_len); memset(ptr, 0xff, bytes_in_rec); - if (table->in_use->really_abort_on_warning()) + if (get_thd()->really_abort_on_warning()) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_DATA_TOO_LONG, 1); else set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_WARN_DATA_OUT_OF_RANGE, 1); @@ -8650,7 +8671,7 @@ int Field_bit_as_char::store(const char *from, uint length, CHARSET_INFO *cs) memset(ptr, 0xff, bytes_in_rec); if (bits) *ptr&= ((1 << bits) - 1); /* set first uchar */ - if (table->in_use->really_abort_on_warning()) + if (get_thd()->really_abort_on_warning()) set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_DATA_TOO_LONG, 1); else set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, ER_WARN_DATA_OUT_OF_RANGE, 1); @@ -9752,7 +9773,7 @@ void Field::set_datetime_warning(MYSQL_ERROR::enum_warning_level level, uint code, const ErrConv *str, timestamp_type ts_type, int cuted_increment) { - THD *thd= table->in_use; + THD *thd= get_thd(); if (thd->really_abort_on_warning() && level >= MYSQL_ERROR::WARN_LEVEL_WARN) make_truncated_value_warning(thd, level, str, ts_type, field_name); else diff --git a/sql/field.h b/sql/field.h index ec09353c3de..9d2fcd9ee58 100644 --- a/sql/field.h +++ b/sql/field.h @@ -36,6 +36,8 @@ class Protocol; class Create_field; class Relay_log_info; class Field; +class Column_statistics; +class Column_statistics_collected; enum enum_check_fields { @@ -173,6 +175,7 @@ public: */ TABLE *table; // Pointer for table TABLE *orig_table; // Pointer to original table + THD *thd; // Used when table == NULL const char * const *table_name; const char *field_name; /** reference to the list of options or NULL */ @@ -220,89 +223,16 @@ public: bool is_stat_field; /* TRUE in Field objects created for column min/max values */ - /* Statistical data on a column */ - class Column_statistics - { - private: - static const uint Scale_factor_nulls_ratio= 100000; - static const uint Scale_factor_avg_length= 100000; - static const uint Scale_factor_avg_frequency= 100000; - public: - /* - Bitmap indicating what statistical characteristics - are available for the column - */ - uint32 column_stat_nulls; - - /* Minimum value for the column */ - Field *min_value; - /* Maximum value for the column */ - Field *max_value; - private: - /* - The ratio Z/N multiplied by the scale factor Scale_factor_nulls_ratio, - where N is the total number of rows, - Z is the number of nulls in the column - */ - ulong nulls_ratio; - /* - Average number of bytes occupied by the representation of a - value of the column in memory buffers such as join buffer - multiplied by the scale factor Scale_factor_avg_length - CHAR values are stripped of trailing spaces - Flexible values are stripped of their length prefixes. - */ - ulong avg_length; - /* - The ratio N/D multiplied by the scale factor Scale_factor_avg_frequency, - where N is the number of rows with null value - in the column, D the number of distinct values among them - */ - ulong avg_frequency; - - public: - double get_nulls_ratio() - { - return (double) nulls_ratio / Scale_factor_nulls_ratio; - } - double get_avg_length() - { - return (double) avg_length / Scale_factor_avg_length; - } - double get_avg_frequency() - { - return (double) avg_frequency / Scale_factor_avg_frequency; - } - - void set_nulls_ratio (double val) - { - nulls_ratio= (ulong) (val * Scale_factor_nulls_ratio); - } - void set_avg_length (double val) - { - avg_length= (ulong) (val * Scale_factor_avg_length); - } - void set_avg_frequency (double val) - { - avg_frequency= (ulong) (val * Scale_factor_avg_frequency); - } - }; - /* This structure is used for statistical data on the column that has been read from the statistical table column_stat */ - Column_statistics read_stat; + Column_statistics *read_stats; /* This structure is used for statistical data on the column that is collected by the function collect_statistics_for_table */ - Column_statistics write_stat; - - /* These members are used only when collecting statistics on the column */ - ha_rows nulls; - ulonglong column_total_length; - Count_distinct_field *count_distinct; + Column_statistics_collected *collected_stats; /* This is additional data provided for any computed(virtual) field. @@ -522,6 +452,8 @@ public: */ inline bool real_maybe_null(void) { return null_ptr != 0; } + inline THD *get_thd() { return table ? table->in_use : thd; } + enum { LAST_NULL_BYTE_UNDEF= 0 }; @@ -560,6 +492,7 @@ public: Field *clone(MEM_ROOT *mem_root, TABLE *new_table); Field *clone(MEM_ROOT *mem_root, TABLE *new_table, my_ptrdiff_t diff, bool stat_flag= FALSE); + Field *clone(THD *thd_arg, MEM_ROOT *mem_root, my_ptrdiff_t diff); inline void move_field(uchar *ptr_arg,uchar *null_ptr_arg,uchar null_bit_arg) { ptr=ptr_arg; null_ptr=null_ptr_arg; null_bit=null_bit_arg; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index a25e496dddc..343b01dbf37 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -484,6 +484,7 @@ ulong refresh_version; /* Increments on each reload */ query_id_t global_query_id; my_atomic_rwlock_t global_query_id_lock; my_atomic_rwlock_t thread_running_lock; +my_atomic_rwlock_t statistics_lock; ulong aborted_threads, aborted_connects; ulong delayed_insert_timeout, delayed_insert_limit, delayed_queue_size; ulong delayed_insert_threads, delayed_insert_writes, delayed_rows_in_use; @@ -1852,6 +1853,7 @@ void clean_up(bool print_message) sys_var_end(); my_atomic_rwlock_destroy(&global_query_id_lock); my_atomic_rwlock_destroy(&thread_running_lock); + my_atomic_rwlock_destroy(&statistics_lock); mysql_mutex_lock(&LOCK_thread_count); DBUG_PRINT("quit", ("got thread count lock")); ready_to_exit=1; @@ -7275,6 +7277,7 @@ static int mysql_init_variables(void) global_query_id= thread_id= 1L; my_atomic_rwlock_init(&global_query_id_lock); my_atomic_rwlock_init(&thread_running_lock); + my_atomic_rwlock_init(&statistics_lock); strmov(server_version, MYSQL_SERVER_VERSION); threads.empty(); thread_cache.empty(); diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 8f811ab09dd..32f70125973 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -712,6 +712,8 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, thd->variables.use_stat_tables > 0) { if (!(compl_result_code= + alloc_statistics_for_table(thd, table->table)) && + !(compl_result_code= collect_statistics_for_table(thd, table->table))) compl_result_code= update_statistics_for_table(thd, table->table); } diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 79f1c32ab1d..db6b583f01f 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -3138,6 +3138,16 @@ retry_share: while (table_cache_count > table_cache_size && unused_tables) free_cache_entry(unused_tables); + if (thd->variables.use_stat_tables > 0) + { + if (share->table_category != TABLE_CATEGORY_SYSTEM) + { + if (!share->stats_can_be_read && + !alloc_statistics_for_table_share(thd, share, TRUE)) + share->stats_can_be_read= TRUE; + } + } + mysql_mutex_unlock(&LOCK_open); /* make a new table */ @@ -4632,11 +4642,21 @@ open_and_process_table(THD *thd, LEX *lex, TABLE_LIST *tables, goto end; } - if (thd->variables.use_stat_tables > 0) + if (thd->variables.use_stat_tables > 0 && tables->table) { - if (tables->table && tables->table->s && - tables->table->s->table_category != TABLE_CATEGORY_SYSTEM) - (void) read_statistics_for_table(thd, tables->table); + TABLE_SHARE *table_share= tables->table->s; + if (table_share && table_share->table_category != TABLE_CATEGORY_SYSTEM) + { + if (!table_share->stats_can_be_read && + !alloc_statistics_for_table_share(thd, table_share, FALSE)) + table_share->stats_can_be_read= TRUE; + + if (table_share->stats_can_be_read && !table_share->stats_is_read) + { + (void) read_statistics_for_table(thd, tables->table); + table_share->stats_is_read= TRUE; + } + } } process_view_routines: diff --git a/sql/sql_base.h b/sql/sql_base.h index 6c20022f7ee..a8d4951981e 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -314,6 +314,9 @@ int open_and_lock_tables_derived(THD *thd, TABLE_LIST *tables, bool derived); int read_statistics_for_table(THD *thd, TABLE *table); int collect_statistics_for_table(THD *thd, TABLE *table); +int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *share, + bool is_safe); +int alloc_statistics_for_table(THD *thd, TABLE *table); int update_statistics_for_table(THD *thd, TABLE *table); int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab); int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col); diff --git a/sql/sql_select.cc b/sql/sql_select.cc index d132f78e377..edb9f230a2e 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -51,6 +51,7 @@ #include "opt_subselect.h" #include "log_slow.h" #include "sql_derived.h" +#include "sql_statistics.h" #include "debug_sync.h" // DEBUG_SYNC #include @@ -14252,7 +14253,6 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, table->intersect_keys.init(); table->keys_in_use_for_query.init(); table->no_rows_with_nulls= param->force_not_null_cols; - table->read_stat.cardinality_is_null= TRUE; table->s= share; init_tmp_table_share(thd, share, "", 0, tmpname, tmpname); @@ -14690,8 +14690,8 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->ext_key_parts= keyinfo->key_parts; keyinfo->key_length=0; keyinfo->rec_per_key=NULL; - keyinfo->read_stat.init_avg_frequency(NULL); - keyinfo->write_stat.init_avg_frequency(NULL); + keyinfo->read_stats= NULL; + keyinfo->collected_stats= NULL; keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->name= (char*) "group_key"; @@ -14808,7 +14808,8 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, keyinfo->algorithm= HA_KEY_ALG_UNDEF; keyinfo->is_statistics_from_stat_tables= FALSE; keyinfo->rec_per_key=0; - keyinfo->read_stat.init_avg_frequency(NULL); + keyinfo->read_stats= NULL; + keyinfo->collected_stats= NULL; /* Create an extra field to hold NULL bits so that unique indexes on diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 3e3815b6479..3964b08019c 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -26,6 +26,7 @@ #include "sql_base.h" #include "key.h" #include "sql_statistics.h" +#include "my_atomic.h" /* The system variable 'use_stat_tables' can take one of the @@ -79,6 +80,7 @@ static const LEX_STRING stat_tables_db_name= { C_STRING_WITH_LEN("mysql") }; otherwise it is set to TL_WRITE. */ +static inline void init_table_list_for_stat_tables(TABLE_LIST *tables, bool for_write) { uint i; @@ -109,6 +111,7 @@ inline void init_table_list_for_stat_tables(TABLE_LIST *tables, bool for_write) otherwise it is set to TL_WRITE. */ +static inline void init_table_list_for_single_stat_table(TABLE_LIST *tbl, const LEX_STRING *stat_tab_name, bool for_write) @@ -125,75 +128,61 @@ inline void init_table_list_for_single_stat_table(TABLE_LIST *tbl, /** @details - The function sets null bits stored in the bitmap table_field->write_stat - for all statistical values collected for a column. -*/ + If the value of the parameter is_safe is TRUE then the function + just copies the address pointed by the parameter src into the memory + pointed by the parameter dest. Otherwise the function performs the + following statement as an atomic action: + if (*dest == NULL) { *dest= *src; } + i.e. the same copying is performed only if *dest is NULL. +*/ -inline void set_nulls_for_write_column_stat_values(Field *table_field) +static +inline void store_address_if_first(void **dest, void **src, bool is_safe) { - table_field->write_stat.column_stat_nulls= - ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << - (COLUMN_STAT_COLUMN_NAME+1); -} - - -/** - @details - The function sets null bits stored in the bitmap table_field->read_stat - for all statistical values collected for a column. -*/ - -inline void set_nulls_for_read_column_stat_values(Field *table_field) -{ - table_field->read_stat.column_stat_nulls= - ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << - (COLUMN_STAT_COLUMN_NAME+1); -} - - -/** - @details - The function removes the null bit stored in the bitmap - table_field->write_stat for the statistical value collected - on the statistical column number stat_field_no. -*/ - -inline void set_not_null_for_write_column_stat_value(Field *table_field, - uint stat_field_no) -{ - table_field->write_stat.column_stat_nulls&= ~(1 << stat_field_no); -} - - -/** - @details - The function removes the null bit stored in the bitmap - table_field->read_stat for the statistical value collected - on the statistical column number stat_field_no. -*/ - -inline void set_not_null_for_read_column_stat_value(Field *table_field, - uint stat_field_no) -{ - table_field->read_stat.column_stat_nulls&= ~(1 << stat_field_no); -} - - -/** - @details - The function checks the null bit stored in the bitmap - table_field->read_stat for the statistical value collected - on the statistical column number stat_field_no. -*/ - -inline bool check_null_for_write_column_stat_value(Field *table_field, - uint stat_field_no) -{ - return table_field->write_stat.column_stat_nulls & (1 << stat_field_no); + if (is_safe) + { + if (!*dest) + memcpy(dest, src, sizeof(void *)); + } + else + { + char *null= NULL; + my_atomic_rwlock_wrlock(statistics_lock); + my_atomic_casptr(dest, (void **) &null, *src) + my_atomic_rwlock_wrunlock(statistics_lock); + } } /* + The class Column_statistics_collected is a helper class used to collect + statistics on a table column. The class is derived directly from + the class Column_statistics, and, additionally to the fields of the + latter, it contains the fields to accumulate the results of aggregation + for the number of nulls in the column and for the size of the column + values. There is also a container for distinct column values used + to calculate the average number of records per distinct column value. +*/ + +class Column_statistics_collected :public Column_statistics +{ + +private: + Field *column; /* The column to collect statistics on */ + ha_rows nulls; /* To accumulate the number of nulls in the column */ + ulonglong column_total_length; /* To accumulate the size of column values */ + Count_distinct_field *count_distinct; /* The container for distinct + column values */ + +public: + + inline void init(THD *thd, Field * table_field); + inline void add(ha_rows rowno); + inline void finish(ha_rows rows); +}; + + +/** Stat_table is the base class for classes Table_stat, Column_stat and Index_stat. The methods of these classes allow us to read statistical data from statistical tables, write collected statistical data into @@ -215,7 +204,7 @@ inline bool check_null_for_write_column_stat_value(Field *table_field, In some cases the TABLE structure for table t may be undefined. Then the objects of the classes Table_stat, Column_stat and Index stat are created by the alternative constructor that require only the name - of the table t and the name of the database it belongs to. Now the + of the table t and the name of the database it belongs to. Currently the alternative constructors are used only in the cases when some records belonging to the table are to be deleted, or its keys are to be updated @@ -327,9 +316,10 @@ protected: KEY *stat_key_info; /* Structure for the index to access stat_table */ /* Table for which statistical data is read / updated */ - TABLE *table; - LEX_STRING *db_name; /* Name of the database containing 'table' */ - LEX_STRING *table_name; /* Name of the table 'table' */ + TABLE *table; + TABLE_SHARE *table_share; /* Table share for 'table */ + LEX_STRING *db_name; /* Name of the database containing 'table' */ + LEX_STRING *table_name; /* Name of the table 'table' */ void store_record_for_update() { @@ -362,11 +352,13 @@ public: statistics has been collected. */ - Stat_table(TABLE *stat, TABLE *tab) :stat_table(stat), table(tab) + Stat_table(TABLE *stat, TABLE *tab) + :stat_table(stat), table(tab) { + table_share= tab->s; common_init_stat_table(); - db_name= &table->s->db; - table_name= &table->s->table_name; + db_name= &table_share->db; + table_name= &table_share->table_name; } @@ -381,7 +373,7 @@ public: */ Stat_table(TABLE *stat, LEX_STRING *db, LEX_STRING *tab) - :stat_table(stat), table(NULL) + :stat_table(stat), table_share(NULL) { common_init_stat_table(); db_name= db; @@ -532,6 +524,7 @@ public: return FALSE; } + /** @brief Update the table name fields in the current record of stat_table @@ -683,12 +676,12 @@ public: void store_stat_fields() { Field *stat_field= stat_table->field[TABLE_STAT_CARDINALITY]; - if (table->write_stat.cardinality_is_null) + if (table->collected_stats->cardinality_is_null) stat_field->set_null(); else { stat_field->set_notnull(); - stat_field->store(table->write_stat.cardinality); + stat_field->store(table->collected_stats->cardinality); } } @@ -709,15 +702,15 @@ public: void get_stat_values() { - table->read_stat.cardinality_is_null= TRUE; - table->read_stat.cardinality= 0; + table_share->read_stats->cardinality_is_null= TRUE; + table_share->read_stats->cardinality= 0; if (find_stat()) { Field *stat_field= stat_table->field[TABLE_STAT_CARDINALITY]; if (!stat_field->is_null()) { - table->read_stat.cardinality_is_null= FALSE; - table->read_stat.cardinality= stat_field->val_int(); + table_share->read_stats->cardinality_is_null= FALSE; + table_share->read_stats->cardinality= stat_field->val_int(); } } } @@ -890,7 +883,7 @@ public: for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_AVG_FREQUENCY; i++) { Field *stat_field= stat_table->field[i]; - if (check_null_for_write_column_stat_value(table_field, i)) + if (table_field->collected_stats->is_null(i)) stat_field->set_null(); else { @@ -898,30 +891,30 @@ public: switch (i) { case COLUMN_STAT_MIN_VALUE: if (table_field->type() == MYSQL_TYPE_BIT) - stat_field->store(table_field->write_stat.min_value->val_int()); + stat_field->store(table_field->collected_stats->min_value->val_int()); else { - table_field->write_stat.min_value->val_str(&val); + table_field->collected_stats->min_value->val_str(&val); stat_field->store(val.ptr(), val.length(), &my_charset_utf8_bin); } break; case COLUMN_STAT_MAX_VALUE: if (table_field->type() == MYSQL_TYPE_BIT) - stat_field->store(table_field->write_stat.max_value->val_int()); + stat_field->store(table_field->collected_stats->max_value->val_int()); else { - table_field->write_stat.max_value->val_str(&val); + table_field->collected_stats->max_value->val_str(&val); stat_field->store(val.ptr(), val.length(), &my_charset_utf8_bin); } break; case COLUMN_STAT_NULLS_RATIO: - stat_field->store(table_field->write_stat.get_nulls_ratio()); + stat_field->store(table_field->collected_stats->get_nulls_ratio()); break; case COLUMN_STAT_AVG_LENGTH: - stat_field->store(table_field->write_stat.get_avg_length()); + stat_field->store(table_field->collected_stats->get_avg_length()); break; case COLUMN_STAT_AVG_FREQUENCY: - stat_field->store(table_field->write_stat.get_avg_frequency()); + stat_field->store(table_field->collected_stats->get_avg_frequency()); break; } } @@ -947,12 +940,12 @@ public: void get_stat_values() { - set_nulls_for_read_column_stat_values(table_field); + table_field->read_stats->set_all_nulls(); - if (table_field->read_stat.min_value) - table_field->read_stat.min_value->set_null(); - if (table_field->read_stat.max_value) - table_field->read_stat.max_value->set_null(); + if (table_field->read_stats->min_value) + table_field->read_stats->min_value->set_null(); + if (table_field->read_stats->max_value) + table_field->read_stats->max_value->set_null(); if (find_stat()) { @@ -965,30 +958,32 @@ public: if (!stat_field->is_null() && (i > COLUMN_STAT_MAX_VALUE || - (i == COLUMN_STAT_MIN_VALUE && table_field->read_stat.min_value) || - (i == COLUMN_STAT_MAX_VALUE && table_field->read_stat.max_value))) + (i == COLUMN_STAT_MIN_VALUE && + table_field->read_stats->min_value) || + (i == COLUMN_STAT_MAX_VALUE && + table_field->read_stats->max_value))) { - set_not_null_for_read_column_stat_value(table_field, i); + table_field->read_stats->set_not_null(i); switch (i) { case COLUMN_STAT_MIN_VALUE: stat_field->val_str(&val); - table_field->read_stat.min_value->store(val.ptr(), val.length(), - &my_charset_utf8_bin); + table_field->read_stats->min_value->store(val.ptr(), val.length(), + &my_charset_utf8_bin); break; case COLUMN_STAT_MAX_VALUE: stat_field->val_str(&val); - table_field->read_stat.max_value->store(val.ptr(), val.length(), - &my_charset_utf8_bin); + table_field->read_stats->max_value->store(val.ptr(), val.length(), + &my_charset_utf8_bin); break; case COLUMN_STAT_NULLS_RATIO: - table_field->read_stat.set_nulls_ratio(stat_field->val_real()); + table_field->read_stats->set_nulls_ratio(stat_field->val_real()); break; case COLUMN_STAT_AVG_LENGTH: - table_field->read_stat.set_avg_length(stat_field->val_real()); + table_field->read_stats->set_avg_length(stat_field->val_real()); break; case COLUMN_STAT_AVG_FREQUENCY: - table_field->read_stat.set_avg_frequency(stat_field->val_real()); + table_field->read_stats->set_avg_frequency(stat_field->val_real()); break; } } @@ -1047,7 +1042,8 @@ public: The TABLE structure for the table index_stat must be passed as a value for the parameter 'stat'. */ - Index_stat(TABLE *stat, TABLE *tab) :Stat_table(stat, tab) + + Index_stat(TABLE *stat, TABLE*tab) :Stat_table(stat, tab) { common_init_index_stat_table(); } @@ -1155,7 +1151,7 @@ public: { Field *stat_field= stat_table->field[INDEX_STAT_AVG_FREQUENCY]; double avg_frequency= - table_key_info->write_stat.get_avg_frequency(prefix_arity-1); + table_key_info->collected_stats->get_avg_frequency(prefix_arity-1); if (avg_frequency == 0) stat_field->set_null(); else @@ -1191,7 +1187,7 @@ public: if (!stat_field->is_null()) avg_frequency= stat_field->val_real(); } - table_key_info->read_stat.set_avg_frequency(prefix_arity-1, avg_frequency); + table_key_info->read_stats->set_avg_frequency(prefix_arity-1, avg_frequency); } }; @@ -1464,7 +1460,7 @@ public: { double val= state->prefix_count == 0 ? 0 : (double) state->entry_count / state->prefix_count; - index_info->write_stat.set_avg_frequency(i, val); + index_info->collected_stats->set_avg_frequency(i, val); } } } @@ -1473,30 +1469,30 @@ public: /** @brief - Create fields for min/max values to collect/read column statistics + Create fields for min/max values to collect column statistics @param table Table the fields are created for - @param - for_write Those fields are created that are used to collect statistics - @note + @details The function first allocates record buffers to store min/max values for 'table's fields. Then for each table field f it creates Field structures that points to these buffers rather that to the record buffer as the Field object for f does. The pointers of the created fields are placed - either in the write_stat or in the read_stat structure of the Field - object for f, depending on the value of the 'for_write' parameter. + in the collected_stats structure of the Field object for f. + The function allocates the buffers for min/max values in the table + memory. @note The buffers allocated when min/max values are used to read statistics from the persistent statistical tables differ from those buffers that - are used when statistics on min/max values for column is collected. + are used when statistics on min/max values for column is collected + as they are allocated in different mem_roots. The same is true for the fields created for min/max values. */ static -void create_min_max_stistical_fields(TABLE *table, bool for_write) +void create_min_max_stistical_fields_for_table(TABLE *table) { Field *table_field; Field **field_ptr; @@ -1506,12 +1502,8 @@ void create_min_max_stistical_fields(TABLE *table, bool for_write) for (field_ptr= table->field; *field_ptr; field_ptr++) { table_field= *field_ptr; - if (for_write) - table_field->write_stat.max_value= - table_field->write_stat.min_value= NULL; - else - table_field->read_stat.max_value= - table_field->read_stat.min_value= NULL; + table_field->collected_stats->max_value= + table_field->collected_stats->min_value= NULL; } if ((record= (uchar *) alloc_root(&table->mem_root, 2*rec_buff_length))) @@ -1523,28 +1515,384 @@ void create_min_max_stistical_fields(TABLE *table, bool for_write) Field *fld; table_field= *field_ptr; my_ptrdiff_t diff= record-table->record[0]; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; if (!(fld= table_field->clone(&table->mem_root, table, diff, TRUE))) continue; if (i == 0) - { - if (for_write) - table_field->write_stat.min_value= fld; - else - table_field->read_stat.min_value= fld; - } + table_field->collected_stats->min_value= fld; else - { - if (for_write) - table_field->write_stat.max_value= fld; - else - table_field->read_stat.max_value= fld; - } + table_field->collected_stats->max_value= fld; } } } } +/** + @brief + Create fields for min/max values to read column statistics + + @param + thd Thread handler + @param + table_share Table share the fields are created for + @param + is_safe TRUE <-> at any time only one thread can perform the function + + @details + The function first allocates record buffers to store min/max values + for 'table_share's fields. Then for each field f it creates Field structures + that points to these buffers rather that to the record buffer as the + Field object for f does. The pointers of the created fields are placed + in the read_stats structure of the Field object for f. + The function allocates the buffers for min/max values in the table share + memory. + If the parameter is_safe is TRUE then it is guaranteed that at any given time + only one thread is executed the code of the function. + + @note + The buffers allocated when min/max values are used to collect statistics + from the persistent statistical tables differ from those buffers that + are used when statistics on min/max values for column is read as they + are allocated in different mem_roots. + The same is true for the fields created for min/max values. +*/ + +static +void create_min_max_stistical_fields_for_table_share(THD *thd, + TABLE_SHARE *table_share, + bool is_safe) +{ + Field *table_field; + Field **field_ptr; + uchar *record; + uint rec_buff_length= table_share->rec_buff_length; + + for (field_ptr= table_share->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + table_field->read_stats->max_value= + table_field->read_stats->min_value= NULL; + } + + if ((record= (uchar *) alloc_root(&table_share->mem_root, 2*rec_buff_length))) + { + for (uint i=0; i < 2; i++, record+= rec_buff_length) + { + for (field_ptr= table_share->field; *field_ptr; field_ptr++) + { + Field *fld; + table_field= *field_ptr; + my_ptrdiff_t diff= record - table_share->default_values; + if (!(fld= table_field->clone(thd, &table_share->mem_root, diff))) + continue; + store_address_if_first(i == 0 ? + (void **) &table_field->read_stats->min_value : + (void **) &table_field->read_stats->max_value, + (void **) &fld, + is_safe); + } + } + } +} + + +/** + @brief + Allocate memory for the table's statistical data to be collected + + @param + table Table for which the memory for statistical data is allocated + + @note + The function allocates the memory for the statistical data on 'table' with + the intention to collect the data there. The memory is allocated for + the statistics on the table, on the table's columns, and on the table's + indexes. The memory is allocated in the table's mem_root. + + @retval + 0 If the memory for all statistical data has been successfully allocated + @retval + 1 Otherwise + + @note + Each thread allocates its own memory to collect statistics on the table + It allows us, for example, to collect statistics on the different indexes + of the same table in parallel. +*/ + +int alloc_statistics_for_table(THD* thd, TABLE *table) +{ + Field **field_ptr; + uint cnt= 0; + + DBUG_ENTER("alloc_statistics_for_table"); + + Table_statistics *table_stats= + (Table_statistics *) alloc_root(&table->mem_root, + sizeof(Table_statistics)); + + for (field_ptr= table->field; *field_ptr; field_ptr++, cnt++) ; + Column_statistics_collected *column_stats= + (Column_statistics_collected *) alloc_root(&table->mem_root, + sizeof(Column_statistics_collected) * cnt); + + uint keys= table->s->keys; + Index_statistics *index_stats= + (Index_statistics *) alloc_root(&table->mem_root, + sizeof(Index_statistics) * keys); + + uint key_parts= table->s->ext_key_parts; + ulong *idx_avg_frequency= (ulong*) alloc_root(&table->mem_root, + sizeof(ulong) * key_parts); + + if (!table_stats || !column_stats || !index_stats || !idx_avg_frequency) + DBUG_RETURN(1); + + table->collected_stats= table_stats; + table_stats->column_stats= column_stats; + table_stats->index_stats= index_stats; + table_stats->idx_avg_frequency= idx_avg_frequency; + + bzero(column_stats, sizeof(Column_statistics) * cnt); + + for (field_ptr= table->field; *field_ptr; field_ptr++, column_stats++) + (*field_ptr)->collected_stats= column_stats; + + bzero(idx_avg_frequency, sizeof(ulong) * key_parts); + + KEY *key_info, *end; + for (key_info= table->key_info, end= key_info + table->s->keys; + key_info < end; + key_info++, index_stats++) + { + key_info->collected_stats= index_stats; + key_info->collected_stats->init_avg_frequency(idx_avg_frequency); + idx_avg_frequency+= key_info->ext_key_parts; + } + + create_min_max_stistical_fields_for_table(table); + + DBUG_RETURN(0); +} + + +/** + @brief + Allocate memory for the statistical data used by a table share + + @param + thd Thread handler + @param + table_share Table share for which the memory for statistical data is allocated + @param + is_safe TRUE <-> at any time only one thread can perform the function + + @note + The function allocates the memory for the statistical data on a table in the + table's share memory with the intention to read the statistics there from + the system persistent statistical tables mysql.table_stat, mysql.column_stat, + mysql.index_stat. The memory is allocated for the statistics on the table, + on the tables's columns, and on the table's indexes. The memory is allocated + in the table_share's mem_root. + If the parameter is_safe is TRUE then it is guaranteed that at any given time + only one thread is executed the code of the function. + + @retval + 0 If the memory for all statistical data has been successfully allocated + @retval + 1 Otherwise + + @note + The situation when more than one thread try to allocate memory for + statistical data is rare. It happens under the following scenario: + 1. One thread executes a query over table t with the system variable + 'use_stat_tables' set to 'never'. + 2. After this the second thread sets 'use_stat_tables' to 'preferably' + and executes a query over table t. + 3. Simultaneously the third thread sets 'use_stat_tables' to 'preferably' + and executes a query over table t. + Here the second and the third threads try to allocate the memory for + statistical data at the same time. The precautions are taken to + guarantee the correctness of the allocation. +*/ + +int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, + bool is_safe) +{ + + Field **field_ptr; + uint cnt= 0; + + DBUG_ENTER("alloc_statistics_for_table"); + + DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); + DEBUG_SYNC(thd, "statistics_mem_alloc_start2"); + + Table_statistics *table_stats= + (Table_statistics *) alloc_root(&table_share->mem_root, + sizeof(Table_statistics)); + if (!table_stats) + DBUG_RETURN(1); + bzero(table_stats, sizeof(Table_statistics)); + store_address_if_first((void **) &table_share->read_stats, + (void **) &table_stats, is_safe); + table_stats= table_share->read_stats; + + for (field_ptr= table_share->field; *field_ptr; field_ptr++, cnt++) ; + Column_statistics *column_stats= + (Column_statistics *) alloc_root(&table_share->mem_root, + sizeof(Column_statistics) * cnt); + if (!column_stats) + DBUG_RETURN(1); + bzero(column_stats, sizeof(Column_statistics) * cnt); + store_address_if_first((void **) &table_stats->column_stats, + (void **) &column_stats, is_safe); + column_stats= table_stats->column_stats; + + for (field_ptr= table_share->field; *field_ptr; field_ptr++, column_stats++) + (*field_ptr)->read_stats= column_stats; + + uint keys= table_share->keys; + Index_statistics *index_stats= + (Index_statistics *) alloc_root(&table_share->mem_root, + sizeof(Index_statistics) * keys); + if (!index_stats) + DBUG_RETURN(1); + bzero(index_stats, sizeof(Index_statistics) * keys); + store_address_if_first((void **) &table_stats->index_stats, + (void **) &index_stats, is_safe); + index_stats= table_stats->index_stats; + + uint key_parts= table_share->ext_key_parts; + ulong *idx_avg_frequency= (ulong*) alloc_root(&table_share->mem_root, + sizeof(ulong) * key_parts); + if (!idx_avg_frequency) + DBUG_RETURN(1); + bzero(idx_avg_frequency, sizeof(ulong) * key_parts); + store_address_if_first((void **) &table_stats->idx_avg_frequency, + (void **) &idx_avg_frequency, is_safe); + idx_avg_frequency= table_stats->idx_avg_frequency; + + KEY *key_info, *end; + for (key_info= table_share->key_info, end= key_info + table_share->keys; + key_info < end; + key_info++, index_stats++) + { + key_info->read_stats= index_stats; + key_info->read_stats->init_avg_frequency(idx_avg_frequency); + idx_avg_frequency+= key_info->ext_key_parts; + } + + create_min_max_stistical_fields_for_table_share(thd, table_share, is_safe); + + DBUG_RETURN(0); +} + + +/** + @brief + Initialize the aggregation fields to collect statistics on a column + + @param + thd Thread handler + @param + table_field Column to collect statistics for +*/ + +inline +void Column_statistics_collected::init(THD *thd, Field *table_field) +{ + uint max_heap_table_size= thd->variables.max_heap_table_size; + + column= table_field; + + set_all_nulls(); + + nulls= 0; + column_total_length= 0; + if (table_field->flags & BLOB_FLAG) + count_distinct= NULL; + else + { + count_distinct= + table_field->type() == MYSQL_TYPE_BIT ? + new Count_distinct_field_bit(table_field, max_heap_table_size) : + new Count_distinct_field(table_field, max_heap_table_size); + } + if (count_distinct && !count_distinct->exists()) + count_distinct= NULL; +} + + +/** + @brief + Perform aggregation for a row when collecting statistics on a column + + @param + rowno The order number of the row +*/ + +inline +void Column_statistics_collected::add(ha_rows rowno) +{ + + if (column->is_null()) + nulls++; + else + { + column_total_length+= column->value_length(); + if (min_value && column->update_min(min_value, rowno == nulls)) + set_not_null(COLUMN_STAT_MIN_VALUE); + if (max_value && column->update_max(max_value, rowno == nulls)) + set_not_null(COLUMN_STAT_MAX_VALUE); + if (count_distinct) + count_distinct->add(); + } +} + + +/** + @brief + Get the results of aggregation when collecting the statistics on a column + + @param + rows The total number of rows in the table +*/ + +inline +void Column_statistics_collected::finish(ha_rows rows) +{ + double val; + + if (rows) + { + val= (double) nulls / rows; + set_nulls_ratio(val); + set_not_null(COLUMN_STAT_NULLS_RATIO); + } + if (rows - nulls) + { + val= (double) column_total_length / (rows - nulls); + set_avg_length(val); + set_not_null(COLUMN_STAT_AVG_LENGTH); + } + if (count_distinct) + { + ulonglong distincts= count_distinct->get_value(); + if (distincts) + { + val= (double) (rows - nulls) / distincts; + set_avg_frequency(val); + set_not_null(COLUMN_STAT_AVG_FREQUENCY); + } + delete count_distinct; + count_distinct= NULL; + } +} + + /** @brief Collect statistical data on an index @@ -1586,6 +1934,9 @@ int collect_statistics_for_index(TABLE *table, uint index) Index_prefix_calc index_prefix_calc(table, key_info); DBUG_ENTER("collect_statistics_for_index"); + DEBUG_SYNC(table->in_use, "statistics_collection_start1"); + DEBUG_SYNC(table->in_use, "statistics_collection_start2"); + table->key_read= 1; table->file->extra(HA_EXTRA_KEYREAD); @@ -1673,32 +2024,15 @@ int collect_statistics_for_table(THD *thd, TABLE *table) DBUG_ENTER("collect_statistics_for_table"); - table->write_stat.cardinality_is_null= TRUE; - table->write_stat.cardinality= 0; + table->collected_stats->cardinality_is_null= TRUE; + table->collected_stats->cardinality= 0; - create_min_max_stistical_fields(table, TRUE); - for (field_ptr= table->field; *field_ptr; field_ptr++) { - table_field= *field_ptr; - uint max_heap_table_size= thd->variables.max_heap_table_size; + table_field= *field_ptr; if (!bitmap_is_set(table->read_set, table_field->field_index)) continue; - set_nulls_for_write_column_stat_values(table_field); - table_field->nulls= 0; - table_field->column_total_length= 0; - if (table_field->flags & BLOB_FLAG) - table_field->count_distinct= NULL; - else - { - table_field->count_distinct= - table_field->type() == MYSQL_TYPE_BIT ? - new Count_distinct_field_bit(table_field, max_heap_table_size) : - new Count_distinct_field(table_field, max_heap_table_size); - } - if (table_field->count_distinct && - !table_field->count_distinct->exists()) - table_field->count_distinct= NULL; + table_field->collected_stats->init(thd, table_field); } /* Perform a full table scan to collect statistics on 'table's columns */ @@ -1713,25 +2047,8 @@ int collect_statistics_for_table(THD *thd, TABLE *table) { table_field= *field_ptr; if (!bitmap_is_set(table->read_set, table_field->field_index)) - continue; - if (table_field->is_null()) - table_field->nulls++; - else - { - table_field->column_total_length+= table_field->value_length(); - if (table_field->write_stat.min_value && - table_field->update_min(table_field->write_stat.min_value, - rows == table_field->nulls)) - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_MIN_VALUE); - if (table_field->write_stat.max_value && - table_field->update_max(table_field->write_stat.max_value, - rows == table_field->nulls)) - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_MAX_VALUE); - if (table_field->count_distinct) - table_field->count_distinct->add(); - } + continue; + table_field->collected_stats->add(rows); } rows++; } @@ -1746,43 +2063,15 @@ int collect_statistics_for_table(THD *thd, TABLE *table) */ if (!rc) { - table->write_stat.cardinality_is_null= FALSE; - table->write_stat.cardinality= rows; + table->collected_stats->cardinality_is_null= FALSE; + table->collected_stats->cardinality= rows; for (field_ptr= table->field; *field_ptr; field_ptr++) { - double val; table_field= *field_ptr; if (!bitmap_is_set(table->read_set, table_field->field_index)) continue; - if (rows) - { - val= (double) table_field->nulls / rows; - table_field->write_stat.set_nulls_ratio(val); - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_NULLS_RATIO); - } - if (rows-table_field->nulls) - { - val= (double) table_field->column_total_length / (rows-table_field->nulls); - table_field->write_stat.set_avg_length(val); - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_AVG_LENGTH); - } - if (table_field->count_distinct) - { - ulonglong count_distinct= table_field->count_distinct->get_value(); - if (count_distinct) - { - val= (double) (rows-table_field->nulls) / count_distinct; - table_field->write_stat.set_avg_frequency(val); - set_not_null_for_write_column_stat_value(table_field, - COLUMN_STAT_AVG_FREQUENCY); - } - delete table_field->count_distinct; - table_field->count_distinct= NULL; - } - + table_field->collected_stats->finish(rows); } } @@ -1790,6 +2079,10 @@ int collect_statistics_for_table(THD *thd, TABLE *table) { uint key; key_map::Iterator it(table->keys_in_use_for_query); + + MY_BITMAP *save_read_set= table->read_set; + table->read_set= &table->tmp_set; + bitmap_set_all(table->read_set); /* Collect statistics for indexes */ while ((key= it++) != key_map::Iterator::BITMAP_END) @@ -1797,6 +2090,8 @@ int collect_statistics_for_table(THD *thd, TABLE *table) if ((rc= collect_statistics_for_index(table, key))) break; } + + table->read_set= save_read_set; } DBUG_RETURN(rc); @@ -1954,6 +2249,7 @@ int read_statistics_for_table(THD *thd, TABLE *table) KEY *key_info, *key_info_end; TABLE_LIST tables[STATISTICS_TABLES]; Open_tables_backup open_tables_backup; + TABLE_SHARE *table_share= table->s; DBUG_ENTER("read_statistics_for_table"); @@ -1966,8 +2262,6 @@ int read_statistics_for_table(THD *thd, TABLE *table) DBUG_RETURN(0); } - create_min_max_stistical_fields(table, FALSE); - /* Read statistics from the statistical table table_stat */ stat_table= tables[TABLE_STAT].table; Table_stat table_stat(stat_table, table); @@ -1977,7 +2271,7 @@ int read_statistics_for_table(THD *thd, TABLE *table) /* Read statistics from the statistical table column_stat */ stat_table= tables[COLUMN_STAT].table; Column_stat column_stat(stat_table, table); - for (field_ptr= table->field; *field_ptr; field_ptr++) + for (field_ptr= table_share->field; *field_ptr; field_ptr++) { table_field= *field_ptr; column_stat.set_key_fields(table_field); @@ -1987,10 +2281,11 @@ int read_statistics_for_table(THD *thd, TABLE *table) /* Read statistics from the statistical table index_stat */ stat_table= tables[INDEX_STAT].table; Index_stat index_stat(stat_table, table); - for (key_info= table->key_info, key_info_end= key_info+table->s->keys; + for (key_info= table_share->key_info, + key_info_end= key_info + table_share->keys; key_info < key_info_end; key_info++) { - uint key_parts= table->actual_n_key_parts(key_info); + uint key_parts= key_info->ext_key_parts; for (i= 0; i < key_parts; i++) { index_stat.set_key_fields(key_info, i+1); @@ -1999,13 +2294,13 @@ int read_statistics_for_table(THD *thd, TABLE *table) key_part_map ext_key_part_map= key_info->ext_key_part_map; if (key_info->key_parts != key_info->ext_key_parts && - key_info->read_stat.get_avg_frequency(key_info->key_parts) == 0) + key_info->read_stats->get_avg_frequency(key_info->key_parts) == 0) { - KEY *pk_key_info= table->key_info + table->s->primary_key; + KEY *pk_key_info= table_share->key_info + table_share->primary_key; uint k= key_info->key_parts; uint pk_parts= pk_key_info->key_parts; - ha_rows n_rows= table->read_stat.cardinality; - double k_dist= n_rows / key_info->read_stat.get_avg_frequency(k-1); + ha_rows n_rows= table_share->read_stats->cardinality; + double k_dist= n_rows / key_info->read_stats->get_avg_frequency(k-1); uint m= 0; for (uint j= 0; j < pk_parts; j++) { @@ -2013,32 +2308,33 @@ int read_statistics_for_table(THD *thd, TABLE *table) { for (uint l= k; l < k + m; l++) { - double avg_frequency= pk_key_info->read_stat.get_avg_frequency(j-1); + double avg_frequency= + pk_key_info->read_stats->get_avg_frequency(j-1); set_if_smaller(avg_frequency, 1); - double val= pk_key_info->read_stat.get_avg_frequency(j) / + double val= pk_key_info->read_stats->get_avg_frequency(j) / avg_frequency; - key_info->read_stat.set_avg_frequency (l, val); + key_info->read_stats->set_avg_frequency (l, val); } } else { - double avg_frequency= pk_key_info->read_stat.get_avg_frequency(j); - key_info->read_stat.set_avg_frequency(k + m, avg_frequency); + double avg_frequency= pk_key_info->read_stats->get_avg_frequency(j); + key_info->read_stats->set_avg_frequency(k + m, avg_frequency); m++; } } for (uint l= k; l < k + m; l++) { - double avg_frequency= key_info->read_stat.get_avg_frequency(l); + double avg_frequency= key_info->read_stats->get_avg_frequency(l); if (avg_frequency == 0 || - table->read_stat.cardinality_is_null) + table_share->read_stats->cardinality_is_null) avg_frequency= 1; else if (avg_frequency > 1) { avg_frequency/= k_dist; set_if_bigger(avg_frequency, 1); } - key_info->read_stat.set_avg_frequency(l, avg_frequency); + key_info->read_stats->set_avg_frequency(l, avg_frequency); } } } @@ -2431,15 +2727,16 @@ void set_statistics_for_table(THD *thd, TABLE *table) { uint use_stat_table_mode= thd->variables.use_stat_tables; table->used_stat_records= - (use_stat_table_mode <= 1 || table->read_stat.cardinality_is_null) ? - table->file->stats.records : table->read_stat.cardinality; + (use_stat_table_mode <= 1 || !table->s->read_stats || + table->s->read_stats->cardinality_is_null) ? + table->file->stats.records : table->s->read_stats->cardinality; KEY *key_info, *key_info_end; for (key_info= table->key_info, key_info_end= key_info+table->s->keys; key_info < key_info_end; key_info++) { key_info->is_statistics_from_stat_tables= - (use_stat_table_mode > 1 && - key_info->read_stat.avg_frequency_is_set() && - key_info->read_stat.get_avg_frequency(0) > 0.5); + (use_stat_table_mode > 1 && key_info->read_stats && + key_info->read_stats->avg_frequency_is_inited() && + key_info->read_stats->get_avg_frequency(0) > 0.5); } } diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 1a8cbf6c3f3..14a16170c3b 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -60,4 +60,159 @@ enum enum_index_stat_col INDEX_STAT_AVG_FREQUENCY }; + +class Columns_statistics; +class Index_statistics; + + +/* Statistical data on a table */ + +class Table_statistics +{ + +public: + my_bool cardinality_is_null; /* TRUE if the cardinality is unknown */ + ha_rows cardinality; /* Number of rows in the table */ + Column_statistics *column_stats; /* Array of statistical data for columns */ + Index_statistics *index_stats; /* Array of statistical data for indexes */ + ulong *idx_avg_frequency; /* Array of records per key for index prefixes */ + +}; + + +/* Statistical data on a column */ + +class Column_statistics +{ + +private: + static const uint Scale_factor_nulls_ratio= 100000; + static const uint Scale_factor_avg_length= 100000; + static const uint Scale_factor_avg_frequency= 100000; + +public: + /* + Bitmap indicating what statistical characteristics + are available for the column + */ + uint32 column_stat_nulls; + + /* Minimum value for the column */ + Field *min_value; + /* Maximum value for the column */ + Field *max_value; + +private: + + /* + The ratio Z/N multiplied by the scale factor Scale_factor_nulls_ratio, + where + N is the total number of rows, + Z is the number of nulls in the column + */ + ulong nulls_ratio; + + /* + Average number of bytes occupied by the representation of a + value of the column in memory buffers such as join buffer + multiplied by the scale factor Scale_factor_avg_length. + CHAR values are stripped of trailing spaces. + Flexible values are stripped of their length prefixes. + */ + ulong avg_length; + + /* + The ratio N/D multiplied by the scale factor Scale_factor_avg_frequency, + where + N is the number of rows with not null value in the column, + D the number of distinct values among them + */ + ulong avg_frequency; + +public: + + void set_all_nulls() + { + column_stat_nulls= + ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << + (COLUMN_STAT_COLUMN_NAME+1); + } + + void set_not_null(uint stat_field_no) + { + column_stat_nulls&= ~(1 << stat_field_no); + } + + bool is_null(uint stat_field_no) + { + return test(column_stat_nulls & (1 << stat_field_no)); + } + + double get_nulls_ratio() + { + return (double) nulls_ratio / Scale_factor_nulls_ratio; + } + + double get_avg_length() + { + return (double) avg_length / Scale_factor_avg_length; + } + + double get_avg_frequency() + { + return (double) avg_frequency / Scale_factor_avg_frequency; + } + + void set_nulls_ratio (double val) + { + nulls_ratio= (ulong) (val * Scale_factor_nulls_ratio); + } + + void set_avg_length (double val) + { + avg_length= (ulong) (val * Scale_factor_avg_length); + } + + void set_avg_frequency (double val) + { + avg_frequency= (ulong) (val * Scale_factor_avg_frequency); + } + +}; + + +/* Statistical data on an index prefixes */ + +class Index_statistics +{ + +private: + static const uint Scale_factor_avg_frequency= 100000; + /* + The k-th element of this array contains the ratio N/D + multiplied by the scale factor Scale_factor_avg_frequency, + where N is the number of index entries without nulls + in the first k components, and D is the number of distinct + k-component prefixes among them + */ + ulong *avg_frequency; + +public: + + void init_avg_frequency(ulong *ptr) { avg_frequency= ptr; } + + bool avg_frequency_is_inited() { return avg_frequency != NULL; } + + double get_avg_frequency(uint i) + { + return (double) avg_frequency[i] / Scale_factor_avg_frequency; + } + + void set_avg_frequency(uint i, double val) + { + avg_frequency[i]= (ulong) (val * Scale_factor_avg_frequency); + } + +}; + #endif /* SQL_STATISTICS_H */ diff --git a/sql/structs.h b/sql/structs.h index 4a70820586d..13bb0574b24 100644 --- a/sql/structs.h +++ b/sql/structs.h @@ -29,6 +29,7 @@ struct TABLE; class Field; +class Index_statistics; class THD; @@ -121,43 +122,16 @@ typedef struct st_key { */ ulong *rec_per_key; - /* Statistical data on an index prefixes */ - class Index_statistics - { - private: - static const uint Scale_factor_avg_frequency= 100000; - /* - The k-th element of this array contains the ratio N/D - multiplied by the scale factor Scale_factor_avg_frequency, - where N is the number of index entries without nulls - in the first k components, and D is the number of distinct - k-component prefixes among them - */ - ulong *avg_frequency; - - public: - void init_avg_frequency(ulong *ptr) { avg_frequency= ptr; } - bool avg_frequency_is_set() { return avg_frequency != NULL; } - double get_avg_frequency(uint i) - { - return (double) avg_frequency[i] / Scale_factor_avg_frequency; - } - void set_avg_frequency(uint i, double val) - { - avg_frequency[i]= (ulong) (val * Scale_factor_avg_frequency); - } - }; - /* This structure is used for statistical data on the index that has been read from the statistical table index_stat */ - Index_statistics read_stat; + Index_statistics *read_stats; /* This structure is used for statistical data on the index that is collected by the function collect_statistics_for_table */ - Index_statistics write_stat; + Index_statistics *collected_stats; union { int bdb_return_if_eq; @@ -168,13 +142,8 @@ typedef struct st_key { engine_option_value *option_list; ha_index_option_struct *option_struct; /* structure with parsed options */ - inline double real_rec_per_key(uint i) - { - if (rec_per_key == 0) - return 0; - return (is_statistics_from_stat_tables ? - read_stat.get_avg_frequency(i) : (double) rec_per_key[i]); - } + double real_rec_per_key(uint i); + } KEY; diff --git a/sql/table.cc b/sql/table.cc index 43bb521670e..577b074a171 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -39,6 +39,7 @@ #include "my_bit.h" #include "sql_select.h" #include "sql_derived.h" +#include "sql_statistics.h" #include "mdl.h" // MDL_wait_for_graph_visitor /* INFORMATION_SCHEMA name */ @@ -762,8 +763,6 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, ulong pos, record_offset; ulong *rec_per_key= NULL; ulong rec_buff_length; - ulong *read_avg_frequency= NULL; - ulong *write_avg_frequency= NULL; handler *handler_file= 0; KEY *keyinfo; KEY_PART_INFO *key_part= NULL; @@ -946,14 +945,6 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, if (!(rec_per_key= (ulong*) alloc_root(&share->mem_root, sizeof(ulong) * ext_key_parts))) goto err; - if (!(read_avg_frequency= (ulong*) alloc_root(&share->mem_root, - sizeof(double) * - ext_key_parts))) - goto err; - if (!(write_avg_frequency= (ulong*) alloc_root(&share->mem_root, - sizeof(double) * - ext_key_parts))) - goto err; first_key_part= key_part; first_key_parts= first_keyinfo.key_parts; keyinfo->flags= first_keyinfo.flags; @@ -966,13 +957,9 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, keyinfo->key_part= key_part; keyinfo->rec_per_key= rec_per_key; - keyinfo->read_stat.init_avg_frequency(read_avg_frequency); - keyinfo->write_stat.init_avg_frequency(write_avg_frequency); for (j=keyinfo->key_parts ; j-- ; key_part++) { *rec_per_key++=0; - *read_avg_frequency++= 0; - *write_avg_frequency++= 0; key_part->fieldnr= (uint16) (uint2korr(strpos) & FIELD_NR_MASK); key_part->offset= (uint) uint2korr(strpos+2)-1; key_part->key_type= (uint) uint2korr(strpos+5); @@ -1019,8 +1006,6 @@ static int open_binary_frm(THD *thd, TABLE_SHARE *share, uchar *head, { *key_part++= first_key_part[j]; *rec_per_key++= 0; - *read_avg_frequency++= 0; - *write_avg_frequency++= 0; keyinfo->ext_key_parts++; keyinfo->ext_key_part_map|= 1 << j; } @@ -2416,8 +2401,6 @@ int open_table_from_share(THD *thd, TABLE_SHARE *share, const char *alias, } #endif - outparam->read_stat.cardinality_is_null= TRUE; - if (!(field_ptr = (Field **) alloc_root(&outparam->mem_root, (uint) ((share->fields+1)* sizeof(Field*))))) @@ -5965,7 +5948,8 @@ bool TABLE::add_tmp_key(uint key, uint key_parts, if (!keyinfo->rec_per_key) return TRUE; bzero(keyinfo->rec_per_key, sizeof(ulong)*key_parts); - keyinfo->read_stat.init_avg_frequency(NULL); + keyinfo->read_stats= NULL; + keyinfo->collected_stats= NULL; for (i= 0; i < key_parts; i++) { @@ -6753,6 +6737,14 @@ uint TABLE_SHARE::actual_n_key_parts(THD *thd) } +double KEY::real_rec_per_key(uint i) +{ + if (rec_per_key == 0) + return 0; + return (is_statistics_from_stat_tables ? + read_stats->get_avg_frequency(i) : (double) rec_per_key[i]); +} + /***************************************************************************** ** Instansiate templates *****************************************************************************/ diff --git a/sql/table.h b/sql/table.h index b9a256b132b..e52a1858916 100644 --- a/sql/table.h +++ b/sql/table.h @@ -45,6 +45,7 @@ struct TABLE_LIST; class ACL_internal_schema_access; class ACL_internal_table_access; class Field; +class Table_statistics; /* Used to identify NESTED_JOIN structures within a join (applicable only to @@ -577,6 +578,15 @@ struct TABLE_SHARE KEY *key_info; /* data of keys in database */ uint *blob_field; /* Index to blobs in Field arrray*/ + bool stats_can_be_read; /* Memory for statistical data is allocated */ + bool stats_is_read; /* Statistical data for table has been read + from statistical tables */ + /* + This structure is used for statistical data on the table + that has been read from the statistical table table_stat + */ + Table_statistics *read_stats; + uchar *default_values; /* row with default values */ LEX_STRING comment; /* Comment about table */ CHARSET_INFO *table_charset; /* Default charset of string fields */ @@ -1007,24 +1017,11 @@ public: */ query_id_t query_id; - /* Statistical data on a table */ - class Table_statistics - { - public: - my_bool cardinality_is_null; /* TRUE if the cardinality is unknown */ - ha_rows cardinality; /* Number of rows in the table */ - }; - - /* - This structure is used for statistical data on the table - that has been read from the statistical table table_stat - */ - Table_statistics read_stat; /* This structure is used for statistical data on the table that is collected by the function collect_statistics_for_table */ - Table_statistics write_stat; + Table_statistics *collected_stats; /* The estimate of the number of records in the table used by optimizer */ ha_rows used_stat_records; From 26947f5adb72cd6b8190ee5d5e6d11be6a2448b5 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 27 Jul 2012 12:05:23 -0700 Subject: [PATCH 20/35] Added missing declaration of statistics_lock. Replaced bzero with memset. Added missing --source include/have_debug_sync.inc into stat_tables.test. --- mysql-test/r/stat_tables.result | 2 ++ mysql-test/r/stat_tables_innodb.result | 2 ++ mysql-test/t/stat_tables.test | 3 +++ sql/mysqld.h | 1 + sql/sql_statistics.cc | 16 ++++++++-------- 5 files changed, 16 insertions(+), 8 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 09486d4ce0b..9d62ff357e2 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -369,6 +369,7 @@ revenue revenue 77949.91860000002 set use_stat_tables='preferably'; +set debug_sync='RESET'; select * from mysql.index_stat where table_name='lineitem' order by index_name; db_name table_name index_name prefix_arity avg_frequency dbt3_s001 lineitem PRIMARY 1 4.0033 @@ -436,6 +437,7 @@ set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; use dbt3_s001; set use_stat_tables='preferably'; analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +set debug_sync='RESET'; select * from mysql.index_stat where table_name='lineitem' order by index_name; db_name table_name index_name prefix_arity avg_frequency dbt3_s001 lineitem PRIMARY 1 4.0033 diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 4cb1261b689..59c1aa66790 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -396,6 +396,7 @@ revenue revenue 77949.91860000002 set use_stat_tables='preferably'; +set debug_sync='RESET'; select * from mysql.index_stat where table_name='lineitem' order by index_name; db_name table_name index_name prefix_arity avg_frequency dbt3_s001 lineitem PRIMARY 1 4.0033 @@ -509,6 +510,7 @@ set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; use dbt3_s001; set use_stat_tables='preferably'; analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +set debug_sync='RESET'; select * from mysql.index_stat where table_name='lineitem' order by index_name; db_name table_name index_name prefix_arity avg_frequency dbt3_s001 lineitem PRIMARY 1 4.0033 diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index bdb689228b2..40c4c17c569 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -1,4 +1,5 @@ --source include/have_stat_tables.inc +--source include/have_debug_sync.inc set @save_use_stat_tables=@@use_stat_tables; @@ -192,6 +193,7 @@ connection default; set use_stat_tables='preferably'; disconnect con1; disconnect con2; +set debug_sync='RESET'; # # Test for parallel statistics collection @@ -251,6 +253,7 @@ connection con2; connection default; disconnect con1; disconnect con2; +set debug_sync='RESET'; select * from mysql.index_stat where table_name='lineitem' order by index_name; diff --git a/sql/mysqld.h b/sql/mysqld.h index 69348a45e9a..526f47d821d 100644 --- a/sql/mysqld.h +++ b/sql/mysqld.h @@ -430,6 +430,7 @@ enum enum_query_type typedef int64 query_id_t; extern query_id_t global_query_id; extern my_atomic_rwlock_t global_query_id_lock; +extern my_atomic_rwlock_t statistics_lock; void unireg_end(void) __attribute__((noreturn)); diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 3964b08019c..94503521628 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -85,7 +85,7 @@ inline void init_table_list_for_stat_tables(TABLE_LIST *tables, bool for_write) { uint i; - bzero((char *) &tables[0], sizeof(TABLE_LIST) * STATISTICS_TABLES); + memset((char *) &tables[0], 0, sizeof(TABLE_LIST) * STATISTICS_TABLES); for (i= 0; i < STATISTICS_TABLES; i++) { @@ -116,7 +116,7 @@ inline void init_table_list_for_single_stat_table(TABLE_LIST *tbl, const LEX_STRING *stat_tab_name, bool for_write) { - bzero((char *) tbl, sizeof(TABLE_LIST)); + memset((char *) tbl, 0, sizeof(TABLE_LIST)); tbl->db= stat_tables_db_name.str; tbl->db_length= stat_tables_db_name.length; @@ -1655,12 +1655,12 @@ int alloc_statistics_for_table(THD* thd, TABLE *table) table_stats->index_stats= index_stats; table_stats->idx_avg_frequency= idx_avg_frequency; - bzero(column_stats, sizeof(Column_statistics) * cnt); + memset(column_stats, 0, sizeof(Column_statistics) * cnt); for (field_ptr= table->field; *field_ptr; field_ptr++, column_stats++) (*field_ptr)->collected_stats= column_stats; - bzero(idx_avg_frequency, sizeof(ulong) * key_parts); + memset(idx_avg_frequency, 0, sizeof(ulong) * key_parts); KEY *key_info, *end; for (key_info= table->key_info, end= key_info + table->s->keys; @@ -1735,7 +1735,7 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, sizeof(Table_statistics)); if (!table_stats) DBUG_RETURN(1); - bzero(table_stats, sizeof(Table_statistics)); + memset(table_stats, 0, sizeof(Table_statistics)); store_address_if_first((void **) &table_share->read_stats, (void **) &table_stats, is_safe); table_stats= table_share->read_stats; @@ -1746,7 +1746,7 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, sizeof(Column_statistics) * cnt); if (!column_stats) DBUG_RETURN(1); - bzero(column_stats, sizeof(Column_statistics) * cnt); + memset(column_stats, 0, sizeof(Column_statistics) * cnt); store_address_if_first((void **) &table_stats->column_stats, (void **) &column_stats, is_safe); column_stats= table_stats->column_stats; @@ -1760,7 +1760,7 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, sizeof(Index_statistics) * keys); if (!index_stats) DBUG_RETURN(1); - bzero(index_stats, sizeof(Index_statistics) * keys); + memset(index_stats, 0, sizeof(Index_statistics) * keys); store_address_if_first((void **) &table_stats->index_stats, (void **) &index_stats, is_safe); index_stats= table_stats->index_stats; @@ -1770,7 +1770,7 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, sizeof(ulong) * key_parts); if (!idx_avg_frequency) DBUG_RETURN(1); - bzero(idx_avg_frequency, sizeof(ulong) * key_parts); + memset(idx_avg_frequency, 0, sizeof(ulong) * key_parts); store_address_if_first((void **) &table_stats->idx_avg_frequency, (void **) &idx_avg_frequency, is_safe); idx_avg_frequency= table_stats->idx_avg_frequency; From 6eace757e94e9236c792d3ba718aebb91c9cce77 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 27 Jul 2012 17:33:23 -0700 Subject: [PATCH 21/35] Moved the test cases for parallel execution from stat_tables.test into a separate file stat_tables_par.test because the test cases could not be run with embedded server. --- mysql-test/r/stat_tables.result | 118 -------------- mysql-test/r/stat_tables_innodb.result | 174 --------------------- mysql-test/r/stat_tables_par.result | 167 ++++++++++++++++++++ mysql-test/r/stat_tables_par_innodb.result | 172 ++++++++++++++++++++ mysql-test/t/stat_tables.test | 112 ------------- mysql-test/t/stat_tables_par.test | 153 ++++++++++++++++++ mysql-test/t/stat_tables_par_innodb.test | 12 ++ 7 files changed, 504 insertions(+), 404 deletions(-) create mode 100644 mysql-test/r/stat_tables_par.result create mode 100644 mysql-test/r/stat_tables_par_innodb.result create mode 100644 mysql-test/t/stat_tables_par.test create mode 100644 mysql-test/t/stat_tables_par_innodb.test diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 9d62ff357e2..26f2b602c6b 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -334,124 +334,6 @@ and o_orderkey=l_orderkey and p_partkey=l_partkey; o_orderkey p_partkey 5895 200 set optimizer_switch=@save_optimizer_switch; -flush table lineitem; -set use_stat_tables='never'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24; -revenue -77949.91860000002 -set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24 ; -set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24; -revenue -77949.91860000002 -revenue -77949.91860000002 -set use_stat_tables='preferably'; -set debug_sync='RESET'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -delete from mysql.index_stat -where table_name='lineitem' and -index_name in ('i_l_shipdate', 'i_l_receiptdate'); -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -analyze table lineitem persistent for columns() indexes (i_l_shipdate); -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -delete from mysql.index_stat -where table_name='lineitem' and index_name= 'i_l_shipdate'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -analyze table lineitem persistent for columns() indexes (i_l_shipdate); -set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -analyze table lineitem persistent for columns() indexes (i_l_receiptdate); -set debug_sync='RESET'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 DROP DATABASE dbt3_s001; use test; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 59c1aa66790..3d534dcab29 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -361,180 +361,6 @@ and o_orderkey=l_orderkey and p_partkey=l_partkey; o_orderkey p_partkey 5895 200 set optimizer_switch=@save_optimizer_switch; -flush table lineitem; -set use_stat_tables='never'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24; -revenue -77949.91860000002 -set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24 ; -set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' -and l_shipdate < date '1994-01-01' + interval '1' year -and l_discount between 0.06 - 0.01 and 0.06 + 0.01 -and l_quantity < 24; -revenue -77949.91860000002 -revenue -77949.91860000002 -set use_stat_tables='preferably'; -set debug_sync='RESET'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 2 1.0364 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_commitdate 3 1.0000 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey 2 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_partkey 2 1.0089 -dbt3_s001 lineitem i_l_partkey 3 1.0000 -dbt3_s001 lineitem i_l_receiptdate 3 1.0000 -dbt3_s001 lineitem i_l_receiptdate 2 1.0152 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_shipdate 3 1.0000 -dbt3_s001 lineitem i_l_shipdate 2 1.0149 -dbt3_s001 lineitem i_l_suppkey 2 1.2073 -dbt3_s001 lineitem i_l_suppkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -delete from mysql.index_stat -where table_name='lineitem' and -index_name in ('i_l_shipdate', 'i_l_receiptdate'); -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 2 1.0364 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_commitdate 3 1.0000 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey 2 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_partkey 2 1.0089 -dbt3_s001 lineitem i_l_partkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 2 1.2073 -dbt3_s001 lineitem i_l_suppkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 -analyze table lineitem persistent for columns() indexes (i_l_shipdate); -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 2 1.0364 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_commitdate 3 1.0000 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey 2 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 -dbt3_s001 lineitem i_l_partkey 3 1.0000 -dbt3_s001 lineitem i_l_partkey 2 1.0089 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_shipdate 3 1.0000 -dbt3_s001 lineitem i_l_shipdate 2 1.0149 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_suppkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 2 1.2073 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 -delete from mysql.index_stat -where table_name='lineitem' and index_name= 'i_l_shipdate'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 2 1.0364 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_commitdate 3 1.0000 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey 2 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_partkey 2 1.0089 -dbt3_s001 lineitem i_l_partkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 2 1.2073 -dbt3_s001 lineitem i_l_suppkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 -set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -analyze table lineitem persistent for columns() indexes (i_l_shipdate); -set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; -analyze table lineitem persistent for columns() indexes (i_l_receiptdate); -set debug_sync='RESET'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; -db_name table_name index_name prefix_arity avg_frequency -dbt3_s001 lineitem PRIMARY 1 4.0033 -dbt3_s001 lineitem PRIMARY 2 1.0000 -dbt3_s001 lineitem i_l_commitdate 2 1.0364 -dbt3_s001 lineitem i_l_commitdate 1 2.7160 -dbt3_s001 lineitem i_l_commitdate 3 1.0000 -dbt3_s001 lineitem i_l_orderkey 1 4.0033 -dbt3_s001 lineitem i_l_orderkey 2 1.0000 -dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 -dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 -dbt3_s001 lineitem i_l_orderkey_quantity 3 1.0000 -dbt3_s001 lineitem i_l_partkey 3 1.0000 -dbt3_s001 lineitem i_l_partkey 2 1.0089 -dbt3_s001 lineitem i_l_partkey 1 30.0250 -dbt3_s001 lineitem i_l_receiptdate 1 2.6477 -dbt3_s001 lineitem i_l_shipdate 1 2.6500 -dbt3_s001 lineitem i_l_suppkey 3 1.0000 -dbt3_s001 lineitem i_l_suppkey 2 1.2073 -dbt3_s001 lineitem i_l_suppkey 1 600.5000 -dbt3_s001 lineitem i_l_suppkey_partkey 3 1.0030 -dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 -dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 -dbt3_s001 lineitem i_l_suppkey_partkey 4 1.0000 DROP DATABASE dbt3_s001; use test; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_par.result b/mysql-test/r/stat_tables_par.result new file mode 100644 index 00000000000..19ecb907a66 --- /dev/null +++ b/mysql-test/r/stat_tables_par.result @@ -0,0 +1,167 @@ +set @save_use_stat_tables=@@use_stat_tables; +set use_stat_tables='preferably'; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 +flush table lineitem; +set use_stat_tables='never'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24 ; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +revenue +77949.91860000002 +set use_stat_tables='preferably'; +set debug_sync='RESET'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +delete from mysql.index_stat +where table_name='lineitem' and +index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +delete from mysql.index_stat +where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +set debug_sync='RESET'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +DROP DATABASE dbt3_s001; +use test; +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_par_innodb.result b/mysql-test/r/stat_tables_par_innodb.result new file mode 100644 index 00000000000..dc290c78dd9 --- /dev/null +++ b/mysql-test/r/stat_tables_par_innodb.result @@ -0,0 +1,172 @@ +SET SESSION STORAGE_ENGINE='InnoDB'; +set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; +set @save_use_stat_tables=@@use_stat_tables; +set use_stat_tables='preferably'; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; +select * from mysql.table_stat; +db_name table_name cardinality +dbt3_s001 customer 150 +dbt3_s001 lineitem 6005 +dbt3_s001 nation 25 +dbt3_s001 orders 1500 +dbt3_s001 part 200 +dbt3_s001 partsupp 700 +dbt3_s001 region 5 +dbt3_s001 supplier 10 +select * from mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 customer PRIMARY 1 1.0000 +dbt3_s001 customer i_c_nationkey 1 6.0000 +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 nation PRIMARY 1 1.0000 +dbt3_s001 nation i_n_regionkey 1 5.0000 +dbt3_s001 orders PRIMARY 1 1.0000 +dbt3_s001 orders i_o_orderdate 1 1.3321 +dbt3_s001 orders i_o_custkey 1 15.0000 +dbt3_s001 part PRIMARY 1 1.0000 +dbt3_s001 partsupp PRIMARY 1 3.5000 +dbt3_s001 partsupp PRIMARY 2 1.0000 +dbt3_s001 partsupp i_ps_partkey 1 3.5000 +dbt3_s001 partsupp i_ps_suppkey 1 70.0000 +dbt3_s001 region PRIMARY 1 1.0000 +dbt3_s001 supplier PRIMARY 1 1.0000 +dbt3_s001 supplier i_s_nationkey 1 1.1111 +flush table lineitem; +set use_stat_tables='never'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24 ; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' +and l_shipdate < date '1994-01-01' + interval '1' year +and l_discount between 0.06 - 0.01 and 0.06 + 0.01 +and l_quantity < 24; +revenue +77949.91860000002 +revenue +77949.91860000002 +set use_stat_tables='preferably'; +set debug_sync='RESET'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +delete from mysql.index_stat +where table_name='lineitem' and +index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +delete from mysql.index_stat +where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +analyze table lineitem persistent for columns() indexes (i_l_receiptdate); +set debug_sync='RESET'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; +db_name table_name index_name prefix_arity avg_frequency +dbt3_s001 lineitem PRIMARY 1 4.0033 +dbt3_s001 lineitem PRIMARY 2 1.0000 +dbt3_s001 lineitem i_l_commitdate 1 2.7160 +dbt3_s001 lineitem i_l_orderkey 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 1 4.0033 +dbt3_s001 lineitem i_l_orderkey_quantity 2 1.0404 +dbt3_s001 lineitem i_l_partkey 1 30.0250 +dbt3_s001 lineitem i_l_receiptdate 1 2.6477 +dbt3_s001 lineitem i_l_shipdate 1 2.6500 +dbt3_s001 lineitem i_l_suppkey 1 600.5000 +dbt3_s001 lineitem i_l_suppkey_partkey 1 30.0250 +dbt3_s001 lineitem i_l_suppkey_partkey 2 8.5786 +DROP DATABASE dbt3_s001; +use test; +set use_stat_tables=@save_use_stat_tables; +set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 40c4c17c569..640f9febc75 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -1,5 +1,4 @@ --source include/have_stat_tables.inc ---source include/have_debug_sync.inc set @save_use_stat_tables=@@use_stat_tables; @@ -145,117 +144,6 @@ eval $QQ1; set optimizer_switch=@save_optimizer_switch; -# -# Test for parallel memory allocation for statistical data -# -# assumes that start the code of memory allocation for stats data has this line: -# -# DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); -# DEBUG_SYNC(thd, "statistics_mem_alloc-start2"); -# - -let $Q6= -select sum(l_extendedprice*l_discount) as revenue -from lineitem -where l_shipdate >= date '1994-01-01' - and l_shipdate < date '1994-01-01' + interval '1' year - and l_discount between 0.06 - 0.01 and 0.06 + 0.01 - and l_quantity < 24; - -flush table lineitem; -set use_stat_tables='never'; -eval $Q6; - -connect (con1, localhost, root,,); -connect (con2, localhost, root,,); - -connection con1; -set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; ---send_eval $Q6 - -connection con2; -set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; ---send_eval $Q6 - -connection con1; ---reap - -connection con2; ---reap - -connection default; -set use_stat_tables='preferably'; -disconnect con1; -disconnect con2; -set debug_sync='RESET'; - -# -# Test for parallel statistics collection -# -# assumes that start of stats collection code has this line: -# -# DEBUG_SYNC(thd, "statistics_collection_start1"); -# DEBUG_SYNC(thd, "statistics_collection_start2"); -# - -select * from mysql.index_stat where table_name='lineitem' order by index_name; -delete from mysql.index_stat - where table_name='lineitem' and - index_name in ('i_l_shipdate', 'i_l_receiptdate'); -select * from mysql.index_stat where table_name='lineitem' order by index_name; ---disable_result_log ---disable_warnings -analyze table lineitem persistent for columns() indexes (i_l_shipdate); ---enable_warnings ---enable_result_log -select * from mysql.index_stat where table_name='lineitem' order by index_name; -delete from mysql.index_stat - where table_name='lineitem' and index_name= 'i_l_shipdate'; -select * from mysql.index_stat where table_name='lineitem' order by index_name; - -connect (con1, localhost, root,,); -connect (con2, localhost, root,,); - -connection con1; -set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; -set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; ---send analyze table lineitem persistent for columns() indexes (i_l_shipdate) - -connection con2; -set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; -set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; -use dbt3_s001; -set use_stat_tables='preferably'; ---send analyze table lineitem persistent for columns() indexes (i_l_receiptdate) - -connection con1; ---disable_result_log ---disable_warnings ---reap ---enable_warnings ---enable_result_log - -connection con2; ---disable_result_log ---disable_warnings ---reap ---enable_warnings ---enable_result_log - -connection default; -disconnect con1; -disconnect con2; -set debug_sync='RESET'; - -select * from mysql.index_stat where table_name='lineitem' order by index_name; DROP DATABASE dbt3_s001; diff --git a/mysql-test/t/stat_tables_par.test b/mysql-test/t/stat_tables_par.test new file mode 100644 index 00000000000..27507ccf811 --- /dev/null +++ b/mysql-test/t/stat_tables_par.test @@ -0,0 +1,153 @@ +--source include/have_stat_tables.inc +--source include/have_debug_sync.inc +--source include/not_embedded.inc + +set @save_use_stat_tables=@@use_stat_tables; + +set use_stat_tables='preferably'; + +--disable_warnings +DROP DATABASE IF EXISTS dbt3_s001; +--enable_warnings + +CREATE DATABASE dbt3_s001; + +use dbt3_s001; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/dbt3_s001.inc +delete from mysql.table_stat; +delete from mysql.column_stat; +delete from mysql.index_stat; +ANALYZE TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +--enable_warnings +--enable_result_log +--enable_query_log + +select * from mysql.table_stat; +select * from mysql.index_stat; + + +# +# Test for parallel memory allocation for statistical data +# +# assumes that start the code of memory allocation for stats data has this line: +# +# DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); +# DEBUG_SYNC(thd, "statistics_mem_alloc-start2"); +# + +let $Q6= +select sum(l_extendedprice*l_discount) as revenue +from lineitem +where l_shipdate >= date '1994-01-01' + and l_shipdate < date '1994-01-01' + interval '1' year + and l_discount between 0.06 - 0.01 and 0.06 + 0.01 + and l_quantity < 24; + +flush table lineitem; +set use_stat_tables='never'; +eval $Q6; + +connect (con1, localhost, root,,); +connect (con2, localhost, root,,); + +connection con1; +set debug_sync='statistics_mem_alloc_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send_eval $Q6 + +connection con2; +set debug_sync='statistics_mem_alloc_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_mem_alloc_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send_eval $Q6 + +connection con1; +--reap + +connection con2; +--reap + +connection default; +set use_stat_tables='preferably'; +disconnect con1; +disconnect con2; +set debug_sync='RESET'; + +# +# Test for parallel statistics collection +# +# assumes that start of stats collection code has this line: +# +# DEBUG_SYNC(thd, "statistics_collection_start1"); +# DEBUG_SYNC(thd, "statistics_collection_start2"); +# + +select * from mysql.index_stat where table_name='lineitem' order by index_name; +delete from mysql.index_stat + where table_name='lineitem' and + index_name in ('i_l_shipdate', 'i_l_receiptdate'); +select * from mysql.index_stat where table_name='lineitem' order by index_name; +--disable_result_log +--disable_warnings +analyze table lineitem persistent for columns() indexes (i_l_shipdate); +--enable_warnings +--enable_result_log +select * from mysql.index_stat where table_name='lineitem' order by index_name; +delete from mysql.index_stat + where table_name='lineitem' and index_name= 'i_l_shipdate'; +select * from mysql.index_stat where table_name='lineitem' order by index_name; + +connect (con1, localhost, root,,); +connect (con2, localhost, root,,); + +connection con1; +set debug_sync='statistics_collection_start1 WAIT_FOR second_thread_started_too'; +set debug_sync='statistics_collection_start2 SIGNAL first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send analyze table lineitem persistent for columns() indexes (i_l_shipdate) + +connection con2; +set debug_sync='statistics_collection_start1 SIGNAL second_thread_started_too'; +set debug_sync='statistics_collection_start2 WAIT_FOR first_thread_working'; +use dbt3_s001; +set use_stat_tables='preferably'; +--send analyze table lineitem persistent for columns() indexes (i_l_receiptdate) + +connection con1; +--disable_result_log +--disable_warnings +--reap +--enable_warnings +--enable_result_log + +connection con2; +--disable_result_log +--disable_warnings +--reap +--enable_warnings +--enable_result_log + +connection default; +disconnect con1; +disconnect con2; +set debug_sync='RESET'; + +select * from mysql.index_stat where table_name='lineitem' order by index_name; + +DROP DATABASE dbt3_s001; + +use test; + +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/stat_tables_par_innodb.test b/mysql-test/t/stat_tables_par_innodb.test new file mode 100644 index 00000000000..fd5833e4aaf --- /dev/null +++ b/mysql-test/t/stat_tables_par_innodb.test @@ -0,0 +1,12 @@ +--source include/have_innodb.inc + +SET SESSION STORAGE_ENGINE='InnoDB'; + +set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; + +--source stat_tables_par.test + +set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; + +SET SESSION STORAGE_ENGINE=DEFAULT; From e13cd5abc1fc194eca36ed3ea145a114a3001627 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 30 Jul 2012 10:09:58 -0700 Subject: [PATCH 22/35] Fixed errors in the calls of the macros my_atomic_rwlock_wrlock, my_atomic_rwlock_wrunlock. --- sql/sql_statistics.cc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 94503521628..c5f9ae5c04e 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -147,9 +147,9 @@ inline void store_address_if_first(void **dest, void **src, bool is_safe) else { char *null= NULL; - my_atomic_rwlock_wrlock(statistics_lock); + my_atomic_rwlock_wrlock(&statistics_lock); my_atomic_casptr(dest, (void **) &null, *src) - my_atomic_rwlock_wrunlock(statistics_lock); + my_atomic_rwlock_wrunlock(&statistics_lock); } } From 85db02984f2306691df6acce1caf7f146beb471f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 17 Aug 2012 13:23:49 -0700 Subject: [PATCH 23/35] Fixed bug mdev-464. The value of system variable use_stat_tables was always reset to 0 ('never') by mistake at the launch of the server. --- mysql-test/r/stat_tables.result | 6 ++++++ mysql-test/r/stat_tables_innodb.result | 6 ++++++ mysql-test/t/stat_tables.test | 3 +++ sql/mysqld.cc | 2 -- 4 files changed, 15 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 26f2b602c6b..5d098bc9ef9 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -1,3 +1,9 @@ +select @@global.use_stat_tables; +@@global.use_stat_tables +COMPLEMENTARY +select @@session.use_stat_tables; +@@session.use_stat_tables +COMPLEMENTARY set @save_use_stat_tables=@@use_stat_tables; set use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 3d534dcab29..2bdc618b566 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -1,6 +1,12 @@ SET SESSION STORAGE_ENGINE='InnoDB'; set @save_optimizer_switch_for_stat_tables_test=@@optimizer_switch; set optimizer_switch='extended_keys=on'; +select @@global.use_stat_tables; +@@global.use_stat_tables +COMPLEMENTARY +select @@session.use_stat_tables; +@@session.use_stat_tables +COMPLEMENTARY set @save_use_stat_tables=@@use_stat_tables; set use_stat_tables='preferably'; DROP DATABASE IF EXISTS dbt3_s001; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 640f9febc75..2ef915cf12c 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -1,5 +1,8 @@ --source include/have_stat_tables.inc +select @@global.use_stat_tables; +select @@session.use_stat_tables; + set @save_use_stat_tables=@@use_stat_tables; set use_stat_tables='preferably'; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index c58fcba4955..1947d42fca5 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -3752,8 +3752,6 @@ static int init_common_variables() global_system_variables.character_set_results= default_charset_info; global_system_variables.character_set_client= default_charset_info; - global_system_variables.use_stat_tables= 0; - if (!(character_set_filesystem= get_charset_by_csname(character_set_filesystem_name, MY_CS_PRIMARY, MYF(MY_WME)))) From 584cfcbebd39981cc144f93cbfb007592e538989 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 18 Aug 2012 11:49:14 -0700 Subject: [PATCH 24/35] Made the process of collecting persistent statistics killable. --- sql/sql_admin.cc | 2 ++ sql/sql_statistics.cc | 14 ++++++++++---- 2 files changed, 12 insertions(+), 4 deletions(-) diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 32f70125973..047b8bac94e 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -716,6 +716,8 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, !(compl_result_code= collect_statistics_for_table(thd, table->table))) compl_result_code= update_statistics_for_table(thd, table->table); + if (compl_result_code) + result_code= HA_ADMIN_FAILED; } if (result_code == HA_ADMIN_NOT_IMPLEMENTED && need_repair_or_alter) diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index c5f9ae5c04e..f58659862c4 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1926,7 +1926,7 @@ void Column_statistics_collected::finish(ha_rows rows) */ static -int collect_statistics_for_index(TABLE *table, uint index) +int collect_statistics_for_index(THD *thd, TABLE *table, uint index) { int rc= 0; KEY *key_info= &table->key_info[index]; @@ -1944,6 +1944,9 @@ int collect_statistics_for_index(TABLE *table, uint index) rc= table->file->ha_index_first(table->record[0]); while (rc != HA_ERR_END_OF_FILE) { + if (thd->killed) + break; + if (rc) break; rows++; @@ -1953,7 +1956,7 @@ int collect_statistics_for_index(TABLE *table, uint index) table->key_read= 0; table->file->ha_index_end(); - rc= (rc == HA_ERR_END_OF_FILE) ? 0 : 1; + rc= (rc == HA_ERR_END_OF_FILE && !thd->killed) ? 0 : 1; if (!rc) index_prefix_calc.get_avg_frequency(); @@ -2040,6 +2043,9 @@ int collect_statistics_for_table(THD *thd, TABLE *table) { while ((rc= file->ha_rnd_next(table->record[0])) != HA_ERR_END_OF_FILE) { + if (thd->killed) + break; + if (rc) break; @@ -2054,7 +2060,7 @@ int collect_statistics_for_table(THD *thd, TABLE *table) } file->ha_rnd_end(); } - rc= rc == HA_ERR_END_OF_FILE ? 0 : 1; + rc= (rc == HA_ERR_END_OF_FILE && !thd->killed) ? 0 : 1; /* Calculate values for all statistical characteristics on columns and @@ -2087,7 +2093,7 @@ int collect_statistics_for_table(THD *thd, TABLE *table) /* Collect statistics for indexes */ while ((key= it++) != key_map::Iterator::BITMAP_END) { - if ((rc= collect_statistics_for_index(table, key))) + if ((rc= collect_statistics_for_index(thd, table, key))) break; } From fd7059d20859863a146cd306b88ac6e9817622fd Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 18 Aug 2012 22:18:46 -0700 Subject: [PATCH 25/35] Fixed the following problem: the syntax of the ANALYZE command did not returned an error if the list of the specified index names contained the name 'primary'. --- mysql-test/r/statistics.result | 19 +++++++++++++++++++ mysql-test/t/statistics.test | 5 +++++ sql/sql_yacc.yy | 29 ++++++++++++++++++----------- 3 files changed, 42 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 680712e5f4a..5a163ca3f84 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -893,6 +893,25 @@ test t1 idx2 2 2.3846 test t1 idx4 1 6.2000 test t1 idx4 2 1.6875 test t1 idx4 3 1.1304 +DELETE FROM mysql.index_stat WHERE table_name='t1' AND index_name='primary'; +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(primary); +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT * FROM mysql.index_stat; +db_name table_name index_name prefix_arity avg_frequency +test t1 idx2 1 7.0000 +test t1 idx2 2 2.3846 +test t1 idx4 1 6.2000 +test t1 idx4 2 1.6875 +test t1 idx4 3 1.1304 +test t1 PRIMARY 1 1.0000 DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 903cf27648c..30aa335e42d 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -353,6 +353,11 @@ SELECT * FROM mysql.table_stat; SELECT * FROM mysql.column_stat; SELECT * FROM mysql.index_stat; +DELETE FROM mysql.index_stat WHERE table_name='t1' AND index_name='primary'; +SELECT * FROM mysql.index_stat; +ANALYZE TABLE t1 PERSISTENT FOR COLUMNS() INDEXES(primary); +SELECT * FROM mysql.index_stat; + DELETE FROM mysql.table_stat; DELETE FROM mysql.column_stat; DELETE FROM mysql.index_stat; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index e2d2b1cac84..13c6cd3aded 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1597,7 +1597,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); analyze_table_list analyze_table_elem_spec opt_persistent_stat_clause persistent_stat_spec persistent_column_stat_spec persistent_index_stat_spec - table_column_list table_index_list + table_column_list table_index_list table_index_name check start checksum field_list field_list_item field_spec kill column_def key_def keycache_list keycache_list_or_parts assign_to_keycache @@ -7312,18 +7312,25 @@ table_column_list: table_index_list: /* empty */ {} - | ident - { - Lex->index_list->push_back((LEX_STRING*) - sql_memdup(&$1, sizeof(LEX_STRING))); - } - | table_index_list ',' ident - { - Lex->index_list->push_back((LEX_STRING*) - sql_memdup(&$3, sizeof(LEX_STRING))); - } + | table_index_name + | table_index_list ',' table_index_name ; +table_index_name: + ident + { + Lex->index_list->push_back( + (LEX_STRING*) sql_memdup(&$1, sizeof(LEX_STRING))); + } + | + PRIMARY_SYM + { + LEX_STRING str= {(char*) "PRIMARY", 7}; + Lex->index_list->push_back( + (LEX_STRING*) sql_memdup(&str, sizeof(LEX_STRING))); + } + ; + binlog_base64_event: BINLOG_SYM TEXT_STRING_sys { From fb69d6426563db40e1558391cecb84ee2eaef8bb Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 20 Aug 2012 12:05:37 -0700 Subject: [PATCH 26/35] Fixed bug mdev-463. RBR should be turned off when an ANALYZE TABLE command is executed. --- mysql-test/r/stat_tables_rbr.result | 10 ++++++++++ mysql-test/t/stat_tables_rbr.test | 18 ++++++++++++++++++ sql/sql_admin.cc | 11 +++++++++++ 3 files changed, 39 insertions(+) create mode 100644 mysql-test/r/stat_tables_rbr.result create mode 100644 mysql-test/t/stat_tables_rbr.test diff --git a/mysql-test/r/stat_tables_rbr.result b/mysql-test/r/stat_tables_rbr.result new file mode 100644 index 00000000000..7a0d23193e7 --- /dev/null +++ b/mysql-test/r/stat_tables_rbr.result @@ -0,0 +1,10 @@ +# +# Bug mdev-463: assertion failure when running ANALYZE with RBR on +# +SET GLOBAL use_stat_tables = PREFERABLY; +CREATE TABLE t1 (i INT) ENGINE=InnoDB; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +DROP TABLE t1; +SET GLOBAL use_stat_tables = DEFAULT; diff --git a/mysql-test/t/stat_tables_rbr.test b/mysql-test/t/stat_tables_rbr.test new file mode 100644 index 00000000000..5297bccf2f4 --- /dev/null +++ b/mysql-test/t/stat_tables_rbr.test @@ -0,0 +1,18 @@ +--source include/have_binlog_format_row.inc +--source include/have_innodb.inc + +--echo # +--echo # Bug mdev-463: assertion failure when running ANALYZE with RBR on +--echo # + +SET GLOBAL use_stat_tables = PREFERABLY; + +--connect (con1,localhost,root,,) +CREATE TABLE t1 (i INT) ENGINE=InnoDB; +ANALYZE TABLE t1; + +# Cleanup +DROP TABLE t1; +SET GLOBAL use_stat_tables = DEFAULT; +--disconnect con1 + diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 047b8bac94e..e00b35a19db 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -322,6 +322,8 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, int result_code; int compl_result_code; bool need_repair_or_alter= 0; + bool save_binlog_row_based= 0; + DBUG_ENTER("mysql_admin_table"); DBUG_PRINT("enter", ("extra_open_options: %u", extra_open_options)); @@ -415,6 +417,11 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, */ open_error= open_and_lock_tables(thd, table, TRUE, 0); + if (lex->sql_command == SQLCOM_ANALYZE) + { + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + } } thd->prepare_derived_at_open= FALSE; @@ -954,6 +961,8 @@ send_result_message: trans_commit_stmt(thd); trans_commit_implicit(thd); close_thread_tables(thd); + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); thd->mdl_context.release_transactional_locks(); /* @@ -986,6 +995,8 @@ err: trans_rollback_stmt(thd); trans_rollback(thd); close_thread_tables(thd); // Shouldn't be needed + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); thd->mdl_context.release_transactional_locks(); if (table) table->table=0; From f4631d6f71c19a98eccf4998eccb49dd69897661 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 23 Aug 2012 11:22:26 -0700 Subject: [PATCH 27/35] Fixed bug mdev-473. With the new code of mysql-5.5 for metadata locking the function unlock_tables_n_open_system_tables_for_write should not explicitly unlock tables for which external locks have been set and should not explicitly reset thd->lock to 0. --- mysql-test/r/stat_tables.result | 11 +++++++++++ mysql-test/r/stat_tables_innodb.result | 11 +++++++++++ mysql-test/t/stat_tables.test | 15 +++++++++++++++ sql/sql_base.cc | 4 ---- 4 files changed, 37 insertions(+), 4 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 5d098bc9ef9..4cc486b10ef 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -342,4 +342,15 @@ o_orderkey p_partkey set optimizer_switch=@save_optimizer_switch; DROP DATABASE dbt3_s001; use test; +# +# Bug mdev-473: ANALYZE table locked for write +# +set use_stat_tables='complementary'; +create table t1 (i int); +lock table t1 write; +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +alter table t1 add column a varchar(8); +drop table t1; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 2bdc618b566..250f24fee02 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -369,6 +369,17 @@ o_orderkey p_partkey set optimizer_switch=@save_optimizer_switch; DROP DATABASE dbt3_s001; use test; +# +# Bug mdev-473: ANALYZE table locked for write +# +set use_stat_tables='complementary'; +create table t1 (i int); +lock table t1 write; +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +alter table t1 add column a varchar(8); +drop table t1; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 2ef915cf12c..67e66a52a6a 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -152,4 +152,19 @@ DROP DATABASE dbt3_s001; use test; +--echo # +--echo # Bug mdev-473: ANALYZE table locked for write +--echo # + +set use_stat_tables='complementary'; + +create table t1 (i int); + +lock table t1 write; +analyze table t1; +alter table t1 add column a varchar(8); + +drop table t1; + + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_base.cc b/sql/sql_base.cc index db6b583f01f..911f2560d85 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -9669,10 +9669,6 @@ unlock_tables_n_open_system_tables_for_write(THD *thd, DBUG_ENTER("unlock_tables_n_open_system_tables_for_write"); - if (thd->lock) - mysql_unlock_tables(thd, thd->lock); - thd->lock= 0; - lex->reset_n_backup_query_tables_list(&query_tables_list_backup); thd->reset_n_backup_open_tables_state(backup); From d0ad93fbc7eca575364e46f67c4613efb0807047 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 27 Aug 2012 14:19:25 -0700 Subject: [PATCH 28/35] Fixed bug mdev-487. The function collect_statistics_for_table() when scanning a table did not take into account that the handler function ha_rnd_next could return the code HA_ERR_RECORD_DELETE that should not be considered as an indication of an error. Also fixed a potential memory leak in this function. --- mysql-test/r/stat_tables.result | 11 ++++++++ mysql-test/r/stat_tables_innodb.result | 11 ++++++++ mysql-test/t/stat_tables.test | 13 ++++++++++ sql/sql_statistics.cc | 36 +++++++++++++++++++++----- 4 files changed, 65 insertions(+), 6 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 4cc486b10ef..3cc650e7050 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -353,4 +353,15 @@ Table Op Msg_type Msg_text test.t1 analyze status Table is already up to date alter table t1 add column a varchar(8); drop table t1; +# +# Bug mdev-487: memory leak in ANALYZE with stat tables +# +SET use_stat_tables = 'preferably'; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1),(2); +DELETE FROM t1 WHERE a=1; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index 250f24fee02..bb0497ee331 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -380,6 +380,17 @@ Table Op Msg_type Msg_text test.t1 analyze status OK alter table t1 add column a varchar(8); drop table t1; +# +# Bug mdev-487: memory leak in ANALYZE with stat tables +# +SET use_stat_tables = 'preferably'; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1),(2); +DELETE FROM t1 WHERE a=1; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 67e66a52a6a..3ef5b4e9b92 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -166,5 +166,18 @@ alter table t1 add column a varchar(8); drop table t1; +--echo # +--echo # Bug mdev-487: memory leak in ANALYZE with stat tables +--echo # + +SET use_stat_tables = 'preferably'; + +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1),(2); +DELETE FROM t1 WHERE a=1; + +ANALYZE TABLE t1; + +DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index f58659862c4..c3d95da007e 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -179,6 +179,7 @@ public: inline void init(THD *thd, Field * table_field); inline void add(ha_rows rowno); inline void finish(ha_rows rows); + inline void cleanup(); }; @@ -1893,6 +1894,22 @@ void Column_statistics_collected::finish(ha_rows rows) } +/** + @brief + Clean up auxiliary structures used for aggregation +*/ + +inline +void Column_statistics_collected::cleanup() +{ + if (count_distinct) + { + delete count_distinct; + count_distinct= NULL; + } +} + + /** @brief Collect statistical data on an index @@ -2047,7 +2064,11 @@ int collect_statistics_for_table(THD *thd, TABLE *table) break; if (rc) + { + if (rc == HA_ERR_RECORD_DELETED) + continue; break; + } for (field_ptr= table->field; *field_ptr; field_ptr++) { @@ -2071,14 +2092,17 @@ int collect_statistics_for_table(THD *thd, TABLE *table) { table->collected_stats->cardinality_is_null= FALSE; table->collected_stats->cardinality= rows; + } - for (field_ptr= table->field; *field_ptr; field_ptr++) - { - table_field= *field_ptr; - if (!bitmap_is_set(table->read_set, table_field->field_index)) - continue; + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + table_field= *field_ptr; + if (!bitmap_is_set(table->read_set, table_field->field_index)) + continue; + if (!rc) table_field->collected_stats->finish(rows); - } + else + table_field->collected_stats->cleanup(); } if (!rc) From cfde11fc4f02e701b856311769d70ccc47d16539 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 1 Sep 2012 23:51:47 -0700 Subject: [PATCH 29/35] Fixed bug mdev-503. If a table is already in the table cache but without data from persistent statistical tables then the function open_and_process_table should not only allocate memory for this statistical data in the corresponding TABLE_SHARE object, but also should copy the references to the data into certain fields of the TABLE data structure: for each key of the table KEY::read_stats should be copied, and for each column of the table Field::read_stats should be copied. --- mysql-test/r/stat_tables_disabled.result | 70 +++++++++++++++++++++ mysql-test/t/stat_tables_disabled.test | 78 ++++++++++++++++++++++++ sql/sql_base.cc | 14 ++++- 3 files changed, 161 insertions(+), 1 deletion(-) create mode 100644 mysql-test/r/stat_tables_disabled.result create mode 100644 mysql-test/t/stat_tables_disabled.test diff --git a/mysql-test/r/stat_tables_disabled.result b/mysql-test/r/stat_tables_disabled.result new file mode 100644 index 00000000000..f57abc34e0c --- /dev/null +++ b/mysql-test/r/stat_tables_disabled.result @@ -0,0 +1,70 @@ +SET SESSION STORAGE_ENGINE='InnoDB'; +select @@global.use_stat_tables; +@@global.use_stat_tables +NEVER +select @@session.use_stat_tables; +@@session.use_stat_tables +NEVER +set @save_use_stat_tables=@@use_stat_tables; +set use_stat_tables='preferably'; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; +# +# Bug mdev-503: optimizer ignores setting use_stat_tables='preferably' +# +flush tables +customer, lineitem, nation, orders, part, partsupp, region, supplier; +set use_stat_tables='never'; +EXPLAIN select sql_calc_found_rows straight_join +l_orderkey, sum(l_extendedprice*(1-l_discount)) as revenue, +o_orderdate, o_shippriority +from orders, customer, lineitem +where c_mktsegment = 'BUILDING' and c_custkey = o_custkey +and l_orderkey = o_orderkey and o_orderdate < date '1995-03-15' + and l_shipdate > date '1995-03-15' +group by l_orderkey, o_orderdate, o_shippriority +order by revenue desc, o_orderdate +limit 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ALL PRIMARY,i_o_orderdate,i_o_custkey NULL NULL NULL # Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey # Using where +1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey # Using where +set use_stat_tables='preferably'; +EXPLAIN select sql_calc_found_rows straight_join +l_orderkey, sum(l_extendedprice*(1-l_discount)) as revenue, +o_orderdate, o_shippriority +from orders, customer, lineitem +where c_mktsegment = 'BUILDING' and c_custkey = o_custkey +and l_orderkey = o_orderkey and o_orderdate < date '1995-03-15' + and l_shipdate > date '1995-03-15' +group by l_orderkey, o_orderdate, o_shippriority +order by revenue desc, o_orderdate +limit 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ALL PRIMARY,i_o_orderdate,i_o_custkey NULL NULL NULL 1500 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +flush tables customer, orders, lineitem; +EXPLAIN select sql_calc_found_rows straight_join +l_orderkey, sum(l_extendedprice*(1-l_discount)) as revenue, +o_orderdate, o_shippriority +from orders, customer, lineitem +where c_mktsegment = 'BUILDING' and c_custkey = o_custkey +and l_orderkey = o_orderkey and o_orderdate < date '1995-03-15' + and l_shipdate > date '1995-03-15' +group by l_orderkey, o_orderdate, o_shippriority +order by revenue desc, o_orderdate +limit 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE orders ALL PRIMARY,i_o_orderdate,i_o_custkey NULL NULL NULL 1500 Using where; Using temporary; Using filesort +1 SIMPLE customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 Using where +1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where +# End of the test case for mdev-503 +set optimizer_switch=@save_optimizer_switch; +DROP DATABASE dbt3_s001; +use test; +set use_stat_tables=@save_use_stat_tables; +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables_disabled.test b/mysql-test/t/stat_tables_disabled.test new file mode 100644 index 00000000000..d42fed33014 --- /dev/null +++ b/mysql-test/t/stat_tables_disabled.test @@ -0,0 +1,78 @@ +--source include/have_innodb.inc + +SET SESSION STORAGE_ENGINE='InnoDB'; + +select @@global.use_stat_tables; +select @@session.use_stat_tables; + +set @save_use_stat_tables=@@use_stat_tables; + +set use_stat_tables='preferably'; + +--disable_warnings +DROP DATABASE IF EXISTS dbt3_s001; +--enable_warnings + +CREATE DATABASE dbt3_s001; + +use dbt3_s001; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='extended_keys=off'; + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/dbt3_s001.inc +delete from mysql.table_stat; +delete from mysql.column_stat; +delete from mysql.index_stat; +ANALYZE TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +--enable_warnings +--enable_result_log +--enable_query_log + +--echo # +--echo # Bug mdev-503: optimizer ignores setting use_stat_tables='preferably' +--echo # + +flush tables +customer, lineitem, nation, orders, part, partsupp, region, supplier; + +let $Q3S= +select sql_calc_found_rows straight_join + l_orderkey, sum(l_extendedprice*(1-l_discount)) as revenue, + o_orderdate, o_shippriority +from orders, customer, lineitem +where c_mktsegment = 'BUILDING' and c_custkey = o_custkey + and l_orderkey = o_orderkey and o_orderdate < date '1995-03-15' + and l_shipdate > date '1995-03-15' +group by l_orderkey, o_orderdate, o_shippriority +order by revenue desc, o_orderdate +limit 10; + +set use_stat_tables='never'; +--replace_column 9 # +eval EXPLAIN $Q3S; + +set use_stat_tables='preferably'; +--replace_result 2 1 +eval EXPLAIN $Q3S; + +flush tables customer, orders, lineitem; +eval EXPLAIN $Q3S; + +--echo # End of the test case for mdev-503 + +set optimizer_switch=@save_optimizer_switch; + + +DROP DATABASE dbt3_s001; + +use test; + +set use_stat_tables=@save_use_stat_tables; + + +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 0dfc98864b1..691add25497 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4652,8 +4652,20 @@ open_and_process_table(THD *thd, LEX *lex, TABLE_LIST *tables, if (table_share && table_share->table_category != TABLE_CATEGORY_SYSTEM) { if (!table_share->stats_can_be_read && - !alloc_statistics_for_table_share(thd, table_share, FALSE)) + !alloc_statistics_for_table_share(thd, table_share, FALSE)) + { + KEY *key_info= table_share->key_info; + KEY *key_info_end= key_info + table_share->keys; + KEY *table_key_info= tables->table->key_info; + for ( ; key_info < key_info_end; key_info++, table_key_info++) + table_key_info->read_stats= key_info->read_stats; + Field **field_ptr= table_share->field; + Field **table_field_ptr= tables->table->field; + for ( ; *field_ptr; field_ptr++, table_field_ptr++) + (*table_field_ptr)->read_stats= (*field_ptr)->read_stats; + table_share->stats_can_be_read= TRUE; + } if (table_share->stats_can_be_read && !table_share->stats_is_read) { From dab998d0e155edbd38b892eaa1478a9f4a0a85b1 Mon Sep 17 00:00:00 2001 From: Elena Stepanova Date: Mon, 3 Sep 2012 22:01:52 +0400 Subject: [PATCH 30/35] Preliminary test case for MDEV-504 in order to reproduce the problem --- mysql-test/r/mdev-504.result | 21 ++++++++++ mysql-test/t/mdev-504.test | 75 ++++++++++++++++++++++++++++++++++++ 2 files changed, 96 insertions(+) create mode 100644 mysql-test/r/mdev-504.result create mode 100644 mysql-test/t/mdev-504.test diff --git a/mysql-test/r/mdev-504.result b/mysql-test/r/mdev-504.result new file mode 100644 index 00000000000..e178127cf2a --- /dev/null +++ b/mysql-test/r/mdev-504.result @@ -0,0 +1,21 @@ +CREATE TABLE A ( +pk INTEGER AUTO_INCREMENT PRIMARY KEY, +fdate DATE +) ENGINE=MyISAM; +CREATE PROCEDURE p_analyze() +BEGIN +DECLARE attempts INTEGER DEFAULT 100; +wl_loop: WHILE attempts > 0 DO +ANALYZE TABLE A; +SET attempts = attempts - 1; +END WHILE wl_loop; +END | +CREATE FUNCTION rnd3() RETURNS INT +BEGIN +RETURN ROUND(3 * RAND() + 0.5); +END | +SET GLOBAL use_stat_tables = PREFERABLY; +DROP TABLE A; +DROP PROCEDURE p_analyze; +DROP FUNCTION rnd3; +SET GLOBAL use_stat_tables = DEFAULT; diff --git a/mysql-test/t/mdev-504.test b/mysql-test/t/mdev-504.test new file mode 100644 index 00000000000..5193581cc47 --- /dev/null +++ b/mysql-test/t/mdev-504.test @@ -0,0 +1,75 @@ +CREATE TABLE A ( + pk INTEGER AUTO_INCREMENT PRIMARY KEY, + fdate DATE +) ENGINE=MyISAM; + +--delimiter | + +CREATE PROCEDURE p_analyze() +BEGIN + DECLARE attempts INTEGER DEFAULT 100; + wl_loop: WHILE attempts > 0 DO + ANALYZE TABLE A; + SET attempts = attempts - 1; + END WHILE wl_loop; +END | + +CREATE FUNCTION rnd3() RETURNS INT +BEGIN + RETURN ROUND(3 * RAND() + 0.5); +END | + +--delimiter ; + +SET GLOBAL use_stat_tables = PREFERABLY; + +--let $trial = 100 + +--disable_query_log +--disable_result_log +--disable_warnings +while ($trial) +{ + + --connect (con1,localhost,root,,) + --send CALL p_analyze() + + --connect (con2,localhost,root,,) + --send CALL p_analyze() + + --let $run = 100 + + while ($run) + { + --connect (con3,localhost,root,,) + + let $query = `SELECT CASE rnd3() + WHEN 1 THEN 'INSERT INTO A (pk) VALUES (NULL)' + WHEN 2 THEN 'DELETE FROM A LIMIT 1' + ELSE 'UPDATE A SET fdate = 2 LIMIT 1' END`; + --eval $query + --disconnect con3 + --dec $run + } + + --connection con2 + --reap + --disconnect con2 + --connection con1 + --reap + --disconnect con1 + + --dec $trial +} + +--enable_query_log +--enable_result_log +--enable_warnings + +# Cleanup +--connection default +DROP TABLE A; +DROP PROCEDURE p_analyze; +DROP FUNCTION rnd3; +SET GLOBAL use_stat_tables = DEFAULT; + From b3f09e8aa04aa3d2d2b86588eddd46badb7e916f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 8 Sep 2012 12:04:31 -0700 Subject: [PATCH 31/35] Fixed bug mdev-504. Opening system statistical tables and reading statistical data from them for a regular table should be done after opening and locking this regular table. No test case is provided with this patch. --- mysql-test/t/stat_tables_par.test | 2 +- sql/sql_base.cc | 10 +- sql/sql_base.h | 2 +- sql/sql_statistics.cc | 156 +++++++++++++++++++++++++----- 4 files changed, 137 insertions(+), 33 deletions(-) diff --git a/mysql-test/t/stat_tables_par.test b/mysql-test/t/stat_tables_par.test index 27507ccf811..1867316b268 100644 --- a/mysql-test/t/stat_tables_par.test +++ b/mysql-test/t/stat_tables_par.test @@ -40,7 +40,7 @@ select * from mysql.index_stat; # assumes that start the code of memory allocation for stats data has this line: # # DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); -# DEBUG_SYNC(thd, "statistics_mem_alloc-start2"); +# DEBUG_SYNC(thd, "statistics_mem_alloc_start2"); # let $Q6= diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 691add25497..f3e180553f0 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4665,13 +4665,7 @@ open_and_process_table(THD *thd, LEX *lex, TABLE_LIST *tables, (*table_field_ptr)->read_stats= (*field_ptr)->read_stats; table_share->stats_can_be_read= TRUE; - } - - if (table_share->stats_can_be_read && !table_share->stats_is_read) - { - (void) read_statistics_for_table(thd, tables->table); - table_share->stats_is_read= TRUE; - } + } } } @@ -5615,6 +5609,8 @@ bool open_and_lock_tables(THD *thd, TABLE_LIST *tables, if (lock_tables(thd, tables, counter, flags)) goto err; + (void) read_statistics_for_tables_if_needed(thd, tables); + if (derived) { if (mysql_handle_derived(thd->lex, DT_INIT)) diff --git a/sql/sql_base.h b/sql/sql_base.h index a8d4951981e..698c4a012e7 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -312,7 +312,7 @@ int dynamic_column_error_message(enum_dyncol_func_result rc); /* open_and_lock_tables with optional derived handling */ int open_and_lock_tables_derived(THD *thd, TABLE_LIST *tables, bool derived); -int read_statistics_for_table(THD *thd, TABLE *table); +int read_statistics_for_tables_if_needed(THD *thd, TABLE_LIST *tables); int collect_statistics_for_table(THD *thd, TABLE *table); int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *share, bool is_safe); diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index c3d95da007e..56db95d40b5 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1726,7 +1726,7 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, Field **field_ptr; uint cnt= 0; - DBUG_ENTER("alloc_statistics_for_table"); + DBUG_ENTER("alloc_statistics_for_table_share"); DEBUG_SYNC(thd, "statistics_mem_alloc_start1"); DEBUG_SYNC(thd, "statistics_mem_alloc_start2"); @@ -2245,6 +2245,8 @@ int update_statistics_for_table(THD *thd, TABLE *table) thd The thread handle @param table The table to read statistics on + @param + stat_tables The array of TABLE_LIST objects for statistical tables @details For each statistical table the function looks for the rows from this @@ -2252,54 +2254,42 @@ int update_statistics_for_table(THD *thd, TABLE *table) the data from statistical columns of it is read into the appropriate fields of internal structures for 'table'. Later at the query processing this data are supposed to be used by the optimizer. - The function is called in function open_tables. + The parameter stat_tables should point to an array of TABLE_LIST + objects for all statistical tables linked into a list. All statistical + tables are supposed to be opened. + The function is called by read_statistics_for_table_if_needed(). @retval - 0 If data has been successfully read from all statistical tables + 0 If data has been successfully read for the table @retval 1 Otherwise @note - The function first calls the function open_system_tables_for_read to - be able to read info from the statistical tables. On success the data is - read from one table after another after which the statistical tables are - closed. Objects of the helper classes Table_stat, Column_stat and Index_stat + Objects of the helper classes Table_stat, Column_stat and Index_stat are employed to read statistical data from the statistical tables. - TODO. Consider a variant when statistical tables are opened and closed - only once for all tables, not for every table of the query as it's done now. */ -int read_statistics_for_table(THD *thd, TABLE *table) +static +int read_statistics_for_table(THD *thd, TABLE *table, TABLE_LIST *stat_tables) { uint i; TABLE *stat_table; Field *table_field; Field **field_ptr; KEY *key_info, *key_info_end; - TABLE_LIST tables[STATISTICS_TABLES]; - Open_tables_backup open_tables_backup; TABLE_SHARE *table_share= table->s; DBUG_ENTER("read_statistics_for_table"); - init_table_list_for_stat_tables(tables, FALSE); - init_mdl_requests(tables); - - if (open_system_tables_for_read(thd, tables, &open_tables_backup)) - { - thd->clear_error(); - DBUG_RETURN(0); - } - /* Read statistics from the statistical table table_stat */ - stat_table= tables[TABLE_STAT].table; + stat_table= stat_tables[TABLE_STAT].table; Table_stat table_stat(stat_table, table); table_stat.set_key_fields(); table_stat.get_stat_values(); /* Read statistics from the statistical table column_stat */ - stat_table= tables[COLUMN_STAT].table; + stat_table= stat_tables[COLUMN_STAT].table; Column_stat column_stat(stat_table, table); for (field_ptr= table_share->field; *field_ptr; field_ptr++) { @@ -2309,7 +2299,7 @@ int read_statistics_for_table(THD *thd, TABLE *table) } /* Read statistics from the statistical table index_stat */ - stat_table= tables[INDEX_STAT].table; + stat_table= stat_tables[INDEX_STAT].table; Index_stat index_stat(stat_table, table); for (key_info= table_share->key_info, key_info_end= key_info + table_share->keys; @@ -2369,6 +2359,124 @@ int read_statistics_for_table(THD *thd, TABLE *table) } } + DBUG_RETURN(0); +} + + +/** + @brief + Check whether any statistics is to be read for tables from a table list + + @param + thd The thread handle + @param + tables The tables list for whose tables the check is to be done + + @details + The function checks whether for any of the tables opened and locked for + a statement statistics from statistical tables is needed to be read. + + @retval + TRUE statistics for any of the tables is needed to be read + @retval + FALSE Otherwise +*/ + +static +bool statistics_for_tables_is_needed(THD *thd, TABLE_LIST *tables) +{ + if (thd->bootstrap || thd->variables.use_stat_tables == 0) + return FALSE; + + if (!tables) + return FALSE; + + switch(thd->lex->sql_command) { + case SQLCOM_SELECT: + case SQLCOM_INSERT: + case SQLCOM_INSERT_SELECT: + case SQLCOM_UPDATE: + case SQLCOM_UPDATE_MULTI: + case SQLCOM_DELETE: + case SQLCOM_DELETE_MULTI: + case SQLCOM_REPLACE: + case SQLCOM_REPLACE_SELECT: + break; + default: + return FALSE; + } + + for (TABLE_LIST *tl= tables; tl; tl= tl->next_global) + { + if (!tl->is_view_or_derived() && tl->table) + { + TABLE_SHARE *table_share= tl->table->s; + if (table_share && + table_share->stats_can_be_read && + !table_share->stats_is_read) + return TRUE; + } + } + + return FALSE; +} + + +/** + @brief + Read statistics for tables from a table list if it is needed + + @param + thd The thread handle + @param + tables The tables list for whose tables to read statistics + + @details + The function first checks whether for any of the tables opened and locked + for a statement statistics from statistical tables is needed to be read. + Then, if so, it opens system statistical tables for read and reads + the statistical data from them for those tables from the list for which it + makes sense. Then the function closes system statistical tables. + + @retval + 0 Statistics for tables was successfully read + @retval + 1 Otherwise +*/ + +int read_statistics_for_tables_if_needed(THD *thd, TABLE_LIST *tables) +{ + TABLE_LIST stat_tables[STATISTICS_TABLES]; + Open_tables_backup open_tables_backup; + + DBUG_ENTER("read_statistics_for_table_if_needed"); + + if (!statistics_for_tables_is_needed(thd, tables)) + DBUG_RETURN(0); + + init_table_list_for_stat_tables(stat_tables, FALSE); + init_mdl_requests(stat_tables); + if (open_system_tables_for_read(thd, stat_tables, &open_tables_backup)) + { + thd->clear_error(); + DBUG_RETURN(1); + } + + for (TABLE_LIST *tl= tables; tl; tl= tl->next_global) + { + if (!tl->is_view_or_derived() && tl->table) + { + TABLE_SHARE *table_share= tl->table->s; + if (table_share && + table_share->stats_can_be_read && + !table_share->stats_is_read) + { + (void) read_statistics_for_table(thd, tl->table, stat_tables); + table_share->stats_is_read= TRUE; + } + } + } + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(0); From 92eadf641590560cbc29ece9c37c7ed493a89468 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 8 Sep 2012 20:33:03 -0700 Subject: [PATCH 32/35] Part 2 of the fix for bug mdev-504. Any Field object should use current_thd instead of table->in_use when THD is needed if table == NULL. This patch fixes the crash of test case from mdev-504.test. --- sql/field.cc | 7 +++---- sql/field.h | 5 ++--- sql/sql_statistics.cc | 2 +- 3 files changed, 6 insertions(+), 8 deletions(-) diff --git a/sql/field.cc b/sql/field.cc index faf1f80610a..610d56ce37a 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -1319,7 +1319,7 @@ String *Field::val_int_as_str(String *val_buffer, bool unsigned_val) Field::Field(uchar *ptr_arg,uint32 length_arg,uchar *null_ptr_arg, uchar null_bit_arg, utype unireg_check_arg, const char *field_name_arg) - :ptr(ptr_arg), null_ptr(null_ptr_arg), table(0), orig_table(0), thd(0), + :ptr(ptr_arg), null_ptr(null_ptr_arg), table(0), orig_table(0), table_name(0), field_name(field_name_arg), option_list(0), option_struct(0), key_start(0), part_of_key(0), part_of_key_not_clustered(0), part_of_sortkey(0), @@ -1874,12 +1874,11 @@ Field *Field::clone(MEM_ROOT *root, TABLE *new_table, my_ptrdiff_t diff, } -Field *Field::clone(THD *thd_arg, MEM_ROOT *root, my_ptrdiff_t diff) +Field *Field::clone(MEM_ROOT *root, my_ptrdiff_t diff) { Field *tmp; if ((tmp= (Field*) memdup_root(root,(char*) this,size_of()))) { - tmp->thd= thd_arg; tmp->move_field_offset(diff); } return tmp; @@ -2780,7 +2779,7 @@ int Field_new_decimal::store(longlong nr, bool unsigned_val) } if (store_value(&decimal_value)) err= 1; - else if (err && !thd->got_warning) + else if (err && !get_thd()->got_warning) err= warn_if_overflow(err); return err; } diff --git a/sql/field.h b/sql/field.h index 9d2fcd9ee58..7ec57698ac9 100644 --- a/sql/field.h +++ b/sql/field.h @@ -175,7 +175,6 @@ public: */ TABLE *table; // Pointer for table TABLE *orig_table; // Pointer to original table - THD *thd; // Used when table == NULL const char * const *table_name; const char *field_name; /** reference to the list of options or NULL */ @@ -452,7 +451,7 @@ public: */ inline bool real_maybe_null(void) { return null_ptr != 0; } - inline THD *get_thd() { return table ? table->in_use : thd; } + inline THD *get_thd() { return table ? table->in_use : current_thd; } enum { LAST_NULL_BYTE_UNDEF= 0 @@ -492,7 +491,7 @@ public: Field *clone(MEM_ROOT *mem_root, TABLE *new_table); Field *clone(MEM_ROOT *mem_root, TABLE *new_table, my_ptrdiff_t diff, bool stat_flag= FALSE); - Field *clone(THD *thd_arg, MEM_ROOT *mem_root, my_ptrdiff_t diff); + Field *clone(MEM_ROOT *mem_root, my_ptrdiff_t diff); inline void move_field(uchar *ptr_arg,uchar *null_ptr_arg,uchar null_bit_arg) { ptr=ptr_arg; null_ptr=null_ptr_arg; null_bit=null_bit_arg; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 56db95d40b5..69da8d81a36 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1586,7 +1586,7 @@ void create_min_max_stistical_fields_for_table_share(THD *thd, Field *fld; table_field= *field_ptr; my_ptrdiff_t diff= record - table_share->default_values; - if (!(fld= table_field->clone(thd, &table_share->mem_root, diff))) + if (!(fld= table_field->clone(&table_share->mem_root, diff))) continue; store_address_if_first(i == 0 ? (void **) &table_field->read_stats->min_value : From ff36e9fc518a4f8b463a09aeb9499c4552a27534 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 10 Sep 2012 22:22:57 -0700 Subject: [PATCH 33/35] Fixed bug mdev-485. RBR should be turned off when statistical tables are modified in the result of the execution of a DDL statement. Revised the fix for bug mdev-463. Ensured suppression of RBR for the modifications of the statistical tables triggered by the execution of any analyze operation. --- mysql-test/r/stat_tables_rbr.result | 15 +++++++ mysql-test/r/stat_tables_repl.result | 41 ++++++++++++++++++++ mysql-test/t/stat_tables_rbr.test | 12 ++++++ mysql-test/t/stat_tables_repl.test | 58 ++++++++++++++++++++++++++++ sql/sql_admin.cc | 10 ----- sql/sql_statistics.cc | 43 +++++++++++++++++++++ 6 files changed, 169 insertions(+), 10 deletions(-) create mode 100644 mysql-test/r/stat_tables_repl.result create mode 100644 mysql-test/t/stat_tables_repl.test diff --git a/mysql-test/r/stat_tables_rbr.result b/mysql-test/r/stat_tables_rbr.result index 7a0d23193e7..0bcf5e9cb93 100644 --- a/mysql-test/r/stat_tables_rbr.result +++ b/mysql-test/r/stat_tables_rbr.result @@ -8,3 +8,18 @@ Table Op Msg_type Msg_text test.t1 analyze status OK DROP TABLE t1; SET GLOBAL use_stat_tables = DEFAULT; +SET use_stat_tables = PREFERABLY; +CREATE TABLE t1 ( a INT ) ENGINE=MyISAM PARTITION BY HASH(a) PARTITIONS 2; +ALTER TABLE t1 ANALYZE PARTITION p1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +SHOW BINLOG EVENTS; +Log_name Pos Event_type Server_id End_log_pos Info +master-bin.000001 4 Format_desc 1 245 Server ver: 5.5.27-MariaDB-debug-log, Binlog ver: 4 +master-bin.000001 245 Query 1 345 use `test`; CREATE TABLE t1 (i INT) ENGINE=InnoDB +master-bin.000001 345 Query 1 424 use `test`; ANALYZE TABLE t1 +master-bin.000001 424 Query 1 528 use `test`; DROP TABLE `t1` /* generated by server */ +master-bin.000001 528 Query 1 664 use `test`; CREATE TABLE t1 ( a INT ) ENGINE=MyISAM PARTITION BY HASH(a) PARTITIONS 2 +master-bin.000001 664 Query 1 762 use `test`; ALTER TABLE t1 ANALYZE PARTITION p1 +SET use_stat_tables = DEFAULT; +DROP TABLE t1; diff --git a/mysql-test/r/stat_tables_repl.result b/mysql-test/r/stat_tables_repl.result new file mode 100644 index 00000000000..370b8c59db1 --- /dev/null +++ b/mysql-test/r/stat_tables_repl.result @@ -0,0 +1,41 @@ +include/master-slave.inc +[connection master] +# +# Bug mdev-485: unexpected failure with replication of DROP/ALTER table +# when RBR is on +# +CREATE TABLE t1 ( a int, b int ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +DROP TABLE t1; +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +DROP INDEX idx1 ON t1; +DROP TABLE t1; +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +ALTER TABLE t1 DROP COLUMN b; +DROP TABLE t1; +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +ALTER TABLE t1 RENAME to s; +DROP TABLE s; +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +ALTER TABLE t1 CHANGE COLUMN b c int ; +DROP TABLE t1; +include/rpl_end.inc diff --git a/mysql-test/t/stat_tables_rbr.test b/mysql-test/t/stat_tables_rbr.test index 5297bccf2f4..9b08357f36e 100644 --- a/mysql-test/t/stat_tables_rbr.test +++ b/mysql-test/t/stat_tables_rbr.test @@ -1,5 +1,6 @@ --source include/have_binlog_format_row.inc --source include/have_innodb.inc +--source include/have_partition.inc --echo # --echo # Bug mdev-463: assertion failure when running ANALYZE with RBR on @@ -16,3 +17,14 @@ DROP TABLE t1; SET GLOBAL use_stat_tables = DEFAULT; --disconnect con1 +--connection default + +SET use_stat_tables = PREFERABLY; + +CREATE TABLE t1 ( a INT ) ENGINE=MyISAM PARTITION BY HASH(a) PARTITIONS 2; +ALTER TABLE t1 ANALYZE PARTITION p1; +SHOW BINLOG EVENTS; + +SET use_stat_tables = DEFAULT; + +DROP TABLE t1; diff --git a/mysql-test/t/stat_tables_repl.test b/mysql-test/t/stat_tables_repl.test new file mode 100644 index 00000000000..999c49d37cf --- /dev/null +++ b/mysql-test/t/stat_tables_repl.test @@ -0,0 +1,58 @@ +--source include/have_stat_tables.inc +--source include/master-slave.inc +--source include/have_binlog_format_row.inc + +--echo # +--echo # Bug mdev-485: unexpected failure with replication of DROP/ALTER table +--echo # when RBR is on +--echo # + +CREATE TABLE t1 ( a int, b int ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +DROP TABLE t1; + +--sync_slave_with_master +--connection master + +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +DROP INDEX idx1 ON t1; + +--sync_slave_with_master +--connection master + +DROP TABLE t1; + +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +ALTER TABLE t1 DROP COLUMN b; + +--sync_slave_with_master +--connection master + +DROP TABLE t1; + +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +ALTER TABLE t1 RENAME to s; + +--sync_slave_with_master +--connection master + +DROP TABLE s; + +CREATE TABLE t1 ( a int, b int, INDEX idx1(b) ) ENGINE=MyISAM; +INSERT INTO t1 VALUES (2,20), (1,20), (3,30); +ANALYZE TABLE t1; +ALTER TABLE t1 CHANGE COLUMN b c int ; + +--sync_slave_with_master +--connection master + +DROP TABLE t1; + +--source include/rpl_end.inc diff --git a/sql/sql_admin.cc b/sql/sql_admin.cc index 1305e882ede..6044207eeaa 100644 --- a/sql/sql_admin.cc +++ b/sql/sql_admin.cc @@ -323,7 +323,6 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, int result_code; int compl_result_code; bool need_repair_or_alter= 0; - bool save_binlog_row_based= 0; DBUG_ENTER("mysql_admin_table"); DBUG_PRINT("enter", ("extra_open_options: %u", extra_open_options)); @@ -418,11 +417,6 @@ static bool mysql_admin_table(THD* thd, TABLE_LIST* tables, */ open_error= open_and_lock_tables(thd, table, TRUE, 0); - if (lex->sql_command == SQLCOM_ANALYZE) - { - if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) - thd->clear_current_stmt_binlog_format_row(); - } } thd->prepare_derived_at_open= FALSE; @@ -962,8 +956,6 @@ send_result_message: trans_commit_stmt(thd); trans_commit_implicit(thd); close_thread_tables(thd); - if (save_binlog_row_based) - thd->set_current_stmt_binlog_format_row(); thd->mdl_context.release_transactional_locks(); /* @@ -996,8 +988,6 @@ err: trans_rollback_stmt(thd); trans_rollback(thd); close_thread_tables(thd); // Shouldn't be needed - if (save_binlog_row_based) - thd->set_current_stmt_binlog_format_row(); thd->mdl_context.release_transactional_locks(); if (table) table->table=0; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 69da8d81a36..7c5086da439 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -2171,6 +2171,7 @@ int update_statistics_for_table(THD *thd, TABLE *table) Open_tables_backup open_tables_backup; uint i; int err; + bool save_binlog_row_based; int rc= 0; TABLE *stat_table; @@ -2187,6 +2188,9 @@ int update_statistics_for_table(THD *thd, TABLE *table) DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + /* Update the statistical table table_stat */ stat_table= tables[TABLE_STAT].table; Table_stat table_stat(stat_table, table); @@ -2231,6 +2235,9 @@ int update_statistics_for_table(THD *thd, TABLE *table) } } + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); @@ -2510,6 +2517,7 @@ int read_statistics_for_tables_if_needed(THD *thd, TABLE_LIST *tables) int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab) { int err; + bool save_binlog_row_based; TABLE *stat_table; TABLE_LIST tables[STATISTICS_TABLES]; Open_tables_backup open_tables_backup; @@ -2528,6 +2536,9 @@ int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab) DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + /* Delete statistics on table from the statistical table index_stat */ stat_table= tables[INDEX_STAT].table; Index_stat index_stat(stat_table, db, tab); @@ -2561,6 +2572,9 @@ int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab) rc= 1; } + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); @@ -2595,6 +2609,7 @@ int delete_statistics_for_table(THD *thd, LEX_STRING *db, LEX_STRING *tab) int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col) { int err; + bool save_binlog_row_based; TABLE *stat_table; TABLE_LIST tables; Open_tables_backup open_tables_backup; @@ -2613,6 +2628,9 @@ int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col) DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + stat_table= tables.table; Column_stat column_stat(stat_table, tab); column_stat.set_key_fields(col); @@ -2623,6 +2641,9 @@ int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col) rc= 1; } + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); @@ -2657,6 +2678,7 @@ int delete_statistics_for_column(THD *thd, TABLE *tab, Field *col) int delete_statistics_for_index(THD *thd, TABLE *tab, KEY *key_info) { int err; + bool save_binlog_row_based; TABLE *stat_table; TABLE_LIST tables; Open_tables_backup open_tables_backup; @@ -2675,6 +2697,9 @@ int delete_statistics_for_index(THD *thd, TABLE *tab, KEY *key_info) DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + stat_table= tables.table; Index_stat index_stat(stat_table, tab); index_stat.set_index_prefix_key_fields(key_info); @@ -2685,6 +2710,9 @@ int delete_statistics_for_index(THD *thd, TABLE *tab, KEY *key_info) rc= 1; } + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); @@ -2722,6 +2750,7 @@ int rename_table_in_stat_tables(THD *thd, LEX_STRING *db, LEX_STRING *tab, LEX_STRING *new_db, LEX_STRING *new_tab) { int err; + bool save_binlog_row_based; TABLE *stat_table; TABLE_LIST tables[STATISTICS_TABLES]; Open_tables_backup open_tables_backup; @@ -2740,6 +2769,9 @@ int rename_table_in_stat_tables(THD *thd, LEX_STRING *db, LEX_STRING *tab, DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + /* Rename table in the statistical table index_stat */ stat_table= tables[INDEX_STAT].table; Index_stat index_stat(stat_table, db, tab); @@ -2775,6 +2807,9 @@ int rename_table_in_stat_tables(THD *thd, LEX_STRING *db, LEX_STRING *tab, rc= 1; } + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); @@ -2812,6 +2847,7 @@ int rename_column_in_stat_tables(THD *thd, TABLE *tab, Field *col, const char *new_name) { int err; + bool save_binlog_row_based; TABLE *stat_table; TABLE_LIST tables; Open_tables_backup open_tables_backup; @@ -2830,6 +2866,9 @@ int rename_column_in_stat_tables(THD *thd, TABLE *tab, Field *col, DBUG_RETURN(rc); } + if ((save_binlog_row_based= thd->is_current_stmt_binlog_format_row())) + thd->clear_current_stmt_binlog_format_row(); + /* Rename column in the statistical table table_stat */ stat_table= tables.table; Column_stat column_stat(stat_table, tab); @@ -2840,6 +2879,10 @@ int rename_column_in_stat_tables(THD *thd, TABLE *tab, Field *col, if (err & !rc) rc= 1; } + + if (save_binlog_row_based) + thd->set_current_stmt_binlog_format_row(); + close_system_tables(thd, &open_tables_backup); DBUG_RETURN(rc); From 2bbcec41488ff4506cb848357086e8fb07a9648c Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 11 Sep 2012 22:36:04 -0700 Subject: [PATCH 34/35] Fixed bug mdev-518. If some statistical tables are corrupted the server should use the conventional statistical data. --- mysql-test/r/stat_tables.result | 16 ++++++++++++++++ mysql-test/r/stat_tables_innodb.result | 16 ++++++++++++++++ mysql-test/t/stat_tables.test | 24 ++++++++++++++++++++++++ sql/sql_statistics.cc | 8 +++++--- 4 files changed, 61 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/stat_tables.result b/mysql-test/r/stat_tables.result index 3cc650e7050..169266fea25 100644 --- a/mysql-test/r/stat_tables.result +++ b/mysql-test/r/stat_tables.result @@ -364,4 +364,20 @@ ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK DROP TABLE t1; +# +# Bug mdev-518: corrupted/missing statistical tables +# +CREATE TABLE t1 (i int) ENGINE=MyISAM; +INSERT INTO t1 VALUES (1),(2); +FLUSH TABLE t1; +SET use_stat_tables='never'; +EXPLAIN SELECT * FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 +FLUSH TABLES; +SET use_stat_tables='preferably'; +EXPLAIN SELECT * FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 +DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/stat_tables_innodb.result b/mysql-test/r/stat_tables_innodb.result index bb0497ee331..699df08225e 100644 --- a/mysql-test/r/stat_tables_innodb.result +++ b/mysql-test/r/stat_tables_innodb.result @@ -391,6 +391,22 @@ ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK DROP TABLE t1; +# +# Bug mdev-518: corrupted/missing statistical tables +# +CREATE TABLE t1 (i int) ENGINE=MyISAM; +INSERT INTO t1 VALUES (1),(2); +FLUSH TABLE t1; +SET use_stat_tables='never'; +EXPLAIN SELECT * FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 +FLUSH TABLES; +SET use_stat_tables='preferably'; +EXPLAIN SELECT * FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 +DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_stat_tables_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/stat_tables.test b/mysql-test/t/stat_tables.test index 3ef5b4e9b92..e3712c8d022 100644 --- a/mysql-test/t/stat_tables.test +++ b/mysql-test/t/stat_tables.test @@ -180,4 +180,28 @@ ANALYZE TABLE t1; DROP TABLE t1; +--echo # +--echo # Bug mdev-518: corrupted/missing statistical tables +--echo # + +CREATE TABLE t1 (i int) ENGINE=MyISAM; +INSERT INTO t1 VALUES (1),(2); + +FLUSH TABLE t1; +SET use_stat_tables='never'; +EXPLAIN SELECT * FROM t1; + +--move_file $MYSQLTEST_VARDIR/mysqld.1/data/mysql/table_stat.MYD $MYSQLTEST_VARDIR/mysqld.1/data/mysql/table_stat.MYD.save + +FLUSH TABLES; +SET use_stat_tables='preferably'; +--disable_warnings +EXPLAIN SELECT * FROM t1; +--enable_warnings + +# Cleanup +--move_file $MYSQLTEST_VARDIR/mysqld.1/data/mysql/table_stat.MYD.save $MYSQLTEST_VARDIR/mysqld.1/data/mysql/table_stat.MYD +DROP TABLE t1; + set use_stat_tables=@save_use_stat_tables; + diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 7c5086da439..412d5722d74 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -2908,15 +2908,17 @@ void set_statistics_for_table(THD *thd, TABLE *table) { uint use_stat_table_mode= thd->variables.use_stat_tables; table->used_stat_records= - (use_stat_table_mode <= 1 || !table->s->read_stats || - table->s->read_stats->cardinality_is_null) ? + (use_stat_table_mode <= 1 || + !table->s->stats_is_read || !table->s->read_stats || + table->s->read_stats->cardinality_is_null) ? table->file->stats.records : table->s->read_stats->cardinality; KEY *key_info, *key_info_end; for (key_info= table->key_info, key_info_end= key_info+table->s->keys; key_info < key_info_end; key_info++) { key_info->is_statistics_from_stat_tables= - (use_stat_table_mode > 1 && key_info->read_stats && + (use_stat_table_mode > 1 && table->s->stats_is_read && + key_info->read_stats && key_info->read_stats->avg_frequency_is_inited() && key_info->read_stats->get_avg_frequency(0) > 0.5); } From 32443e744d354fbba93c8761486462b5820b74bb Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 12 Sep 2012 15:33:03 -0700 Subject: [PATCH 35/35] Made the results from the stat_tables_rbr test to be not dependent on the debug mode. --- mysql-test/r/stat_tables_rbr.result | 2 +- mysql-test/t/stat_tables_rbr.test | 1 + 2 files changed, 2 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/stat_tables_rbr.result b/mysql-test/r/stat_tables_rbr.result index 0bcf5e9cb93..05c5d378bab 100644 --- a/mysql-test/r/stat_tables_rbr.result +++ b/mysql-test/r/stat_tables_rbr.result @@ -15,7 +15,7 @@ Table Op Msg_type Msg_text test.t1 analyze status OK SHOW BINLOG EVENTS; Log_name Pos Event_type Server_id End_log_pos Info -master-bin.000001 4 Format_desc 1 245 Server ver: 5.5.27-MariaDB-debug-log, Binlog ver: 4 +master-bin.000001 4 Format_desc 1 245 Server ver: #, Binlog ver: # master-bin.000001 245 Query 1 345 use `test`; CREATE TABLE t1 (i INT) ENGINE=InnoDB master-bin.000001 345 Query 1 424 use `test`; ANALYZE TABLE t1 master-bin.000001 424 Query 1 528 use `test`; DROP TABLE `t1` /* generated by server */ diff --git a/mysql-test/t/stat_tables_rbr.test b/mysql-test/t/stat_tables_rbr.test index 9b08357f36e..4336c02c34b 100644 --- a/mysql-test/t/stat_tables_rbr.test +++ b/mysql-test/t/stat_tables_rbr.test @@ -23,6 +23,7 @@ SET use_stat_tables = PREFERABLY; CREATE TABLE t1 ( a INT ) ENGINE=MyISAM PARTITION BY HASH(a) PARTITIONS 2; ALTER TABLE t1 ANALYZE PARTITION p1; +--replace_regex /\/\* xid=.* \*\//\/* XID *\// /Server ver: .*, Binlog ver: .*/Server ver: #, Binlog ver: #/ /table_id: [0-9]+/table_id: #/ SHOW BINLOG EVENTS; SET use_stat_tables = DEFAULT;