From fc1c8ffdadfd14eb51969ecfde43e3204f10f6f8 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 11 Mar 2013 07:44:24 -0700 Subject: [PATCH 01/37] The pilot patch for mwl#253. --- mysql-test/r/mysqld--help.result | 13 + mysql-test/r/selectivity.result | 114 ++++++++ mysql-test/r/selectivity_innodb.result | 119 ++++++++ ...zer_use_condition_selectivity_basic.result | 101 +++++++ ...mizer_use_condition_selectivity_basic.test | 138 +++++++++ mysql-test/t/selectivity.test | 65 +++++ mysql-test/t/selectivity_innodb.test | 12 + sql/field.cc | 56 ++++ sql/field.h | 27 +- sql/item_cmpfunc.cc | 20 +- sql/item_cmpfunc.h | 2 + sql/opt_range.cc | 219 ++++++++++++++ sql/opt_range.h | 2 + sql/opt_range_mrr.cc | 6 +- sql/opt_subselect.cc | 2 +- sql/opt_subselect.h | 1 + sql/sql_class.h | 1 + sql/sql_priv.h | 1 + sql/sql_select.cc | 268 ++++++++++++++++-- sql/sql_select.h | 6 + sql/sql_statistics.cc | 49 ++++ sql/sql_statistics.h | 6 + sql/sys_vars.cc | 16 ++ sql/table.cc | 6 +- sql/table.h | 3 + 25 files changed, 1219 insertions(+), 34 deletions(-) create mode 100644 mysql-test/r/selectivity.result create mode 100644 mysql-test/r/selectivity_innodb.result create mode 100644 mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result create mode 100644 mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test create mode 100644 mysql-test/t/selectivity.test create mode 100644 mysql-test/t/selectivity_innodb.test diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index d29631eabc0..afa3a2ac3af 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -500,6 +500,18 @@ The following options may be given as the first argument: partial_match_table_scan, semijoin, semijoin_with_cache, subquery_cache, table_elimination, extended_keys, exists_to_in } and val is one of {on, off, default} + --optimizer-use-condition-selectivity=# + Controls selectivity of which conditions the optimizer + takes into account to calculate cardinality of a partial + join when it searches for the best execution plan + Meaning: 1 - use selectivity of index backed range + conditions to calculate cardinality of the partial join + if the last joined table is accessed by full table scan + or an index scan 2 - use selectivity of index backed + range conditions to calculate cardinality of the partial + join in any case 3 - additionally always use selectivity + of range conditions that are not backed by any index to + calculate cardinality of the partial join --performance-schema Enable the performance schema. --performance-schema-events-waits-history-long-size=# @@ -1004,6 +1016,7 @@ 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-condition-selectivity 1 performance-schema FALSE performance-schema-events-waits-history-long-size 10000 performance-schema-events-waits-history-size 10 diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result new file mode 100644 index 00000000000..3db8da46ea2 --- /dev/null +++ b/mysql-test/r/selectivity.result @@ -0,0 +1,114 @@ +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; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier ALL PRIMARY,i_s_nationkey NULL NULL NULL 10 100.00 Using where; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +1 PRIMARY nation eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 100.00 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 100.00 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`nation`.`n_nationkey` = `dbt3_s001`.`supplier`.`s_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +DROP DATABASE dbt3_s001; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result new file mode 100644 index 00000000000..0a6abfd66d3 --- /dev/null +++ b/mysql-test/r/selectivity_innodb.result @@ -0,0 +1,119 @@ +SET SESSION STORAGE_ENGINE='InnoDB'; +set @save_optimizer_switch_for_selectivity_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; +CREATE DATABASE dbt3_s001; +use dbt3_s001; +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier ALL PRIMARY,i_s_nationkey NULL NULL NULL 10 100.00 Using where; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +1 PRIMARY nation eq_ref PRIMARY PRIMARY 4 dbt3_s001.supplier.s_nationkey 1 100.00 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 100.00 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`nation`.`n_nationkey` = `dbt3_s001`.`supplier`.`s_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +DROP DATABASE dbt3_s001; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +set use_stat_tables=@save_use_stat_tables; +set optimizer_switch=@save_optimizer_switch_for_selectivity_test; +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result b/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result new file mode 100644 index 00000000000..332194e369e --- /dev/null +++ b/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result @@ -0,0 +1,101 @@ +SET @start_global_value = @@global.optimizer_use_condition_selectivity; +SELECT @start_global_value; +@start_global_value +1 +SET @start_session_value = @@session.optimizer_use_condition_selectivity; +SELECT @start_session_value; +@start_session_value +1 +'#--------------------FN_DYNVARS_115_01-------------------------#' +SET @@global.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +1 +SET @@session.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +1 +'#--------------------FN_DYNVARS_115_02-------------------------#' +SET @@global.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@global.optimizer_use_condition_selectivity = 1; +@@global.optimizer_use_condition_selectivity = 1 +1 +SET @@session.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@session.optimizer_use_condition_selectivity = 1; +@@session.optimizer_use_condition_selectivity = 1 +1 +'#--------------------FN_DYNVARS_115_03-------------------------#' +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +1 +SET @@global.optimizer_use_condition_selectivity = 1; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +1 +SET @@global.optimizer_use_condition_selectivity = 2; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +2 +SET @@global.optimizer_use_condition_selectivity = 3; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +3 +'#--------------------FN_DYNVARS_115_04-------------------------#' +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +1 +SET @@session.optimizer_use_condition_selectivity = 1; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +1 +SET @@session.optimizer_use_condition_selectivity = 2; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +2 +SET @@session.optimizer_use_condition_selectivity = 3; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +3 +'#------------------FN_DYNVARS_115_05-----------------------#' +SET @@global.optimizer_use_condition_selectivity = ON; +ERROR 42000: Incorrect argument type to variable 'optimizer_use_condition_selectivity' +SET @@global.optimizer_use_condition_selectivity = OFF; +ERROR 42000: Incorrect argument type to variable 'optimizer_use_condition_selectivity' +SET @@session.optimizer_use_condition_selectivity = 65530.34; +ERROR 42000: Incorrect argument type to variable 'optimizer_use_condition_selectivity' +SET @@session.optimizer_use_condition_selectivity = test; +ERROR 42000: Incorrect argument type to variable 'optimizer_use_condition_selectivity' +'#------------------FN_DYNVARS_115_06-----------------------#' +SELECT @@global.optimizer_use_condition_selectivity = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='optimizer_use_condition_selectivity'; +@@global.optimizer_use_condition_selectivity = VARIABLE_VALUE +1 +'#------------------FN_DYNVARS_115_07-----------------------#' +SELECT @@session.optimizer_use_condition_selectivity = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_use_condition_selectivity'; +@@session.optimizer_use_condition_selectivity = VARIABLE_VALUE +1 +'#---------------------FN_DYNVARS_115_08----------------------#' +SET @@optimizer_use_condition_selectivity = 1; +SET @@global.optimizer_use_condition_selectivity = 3; +SELECT @@optimizer_use_condition_selectivity = @@global.optimizer_use_condition_selectivity; +@@optimizer_use_condition_selectivity = @@global.optimizer_use_condition_selectivity +0 +'#---------------------FN_DYNVARS_115_09----------------------#' +SET @@optimizer_use_condition_selectivity = 2; +SELECT @@optimizer_use_condition_selectivity = @@local.optimizer_use_condition_selectivity; +@@optimizer_use_condition_selectivity = @@local.optimizer_use_condition_selectivity +1 +SELECT @@local.optimizer_use_condition_selectivity = @@session.optimizer_use_condition_selectivity; +@@local.optimizer_use_condition_selectivity = @@session.optimizer_use_condition_selectivity +1 +SET @@global.optimizer_use_condition_selectivity = @start_global_value; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +1 +SET @@session.optimizer_use_condition_selectivity = @start_session_value; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +1 diff --git a/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test b/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test new file mode 100644 index 00000000000..d898cf448dc --- /dev/null +++ b/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test @@ -0,0 +1,138 @@ + +--source include/load_sysvars.inc + +################################################################# +# START OF optimizer_use_condition_selectivity TESTS # +################################################################# + + +############################################################# +# Save initial value # +############################################################# + +SET @start_global_value = @@global.optimizer_use_condition_selectivity; +SELECT @start_global_value; +SET @start_session_value = @@session.optimizer_use_condition_selectivity; +SELECT @start_session_value; + + +--echo '#--------------------FN_DYNVARS_115_01-------------------------#' +######################################################################### +# Display the DEFAULT value of optimizer_use_condition_selectivity # +######################################################################### + +SET @@global.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@global.optimizer_use_condition_selectivity; + +SET @@session.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@session.optimizer_use_condition_selectivity; + + +--echo '#--------------------FN_DYNVARS_115_02-------------------------#' +######################################################################### +# Check the DEFAULT value of optimizer_use_condition_selectivity # +######################################################################### + +SET @@global.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@global.optimizer_use_condition_selectivity = 1; + +SET @@session.optimizer_use_condition_selectivity = DEFAULT; +SELECT @@session.optimizer_use_condition_selectivity = 1; + + +--echo '#--------------------FN_DYNVARS_115_03-------------------------#' +############################################################################################# +# Change the value of optimizer_use_condition_selectivity to a valid value for GLOBAL Scope # +############################################################################################# + +SELECT @@global.optimizer_use_condition_selectivity; +SET @@global.optimizer_use_condition_selectivity = 1; +SELECT @@global.optimizer_use_condition_selectivity; +SET @@global.optimizer_use_condition_selectivity = 2; +SELECT @@global.optimizer_use_condition_selectivity; +SET @@global.optimizer_use_condition_selectivity = 3; +SELECT @@global.optimizer_use_condition_selectivity; + + +--echo '#--------------------FN_DYNVARS_115_04-------------------------#' +############################################################################################# +# Change the value of optimizer_use_condition_selectivity to a valid value for SESSION Scope# +############################################################################################# + +SELECT @@session.optimizer_use_condition_selectivity; +SET @@session.optimizer_use_condition_selectivity = 1; +SELECT @@session.optimizer_use_condition_selectivity; +SET @@session.optimizer_use_condition_selectivity = 2; +SELECT @@session.optimizer_use_condition_selectivity; +SET @@session.optimizer_use_condition_selectivity = 3; +SELECT @@session.optimizer_use_condition_selectivity; + + +--echo '#------------------FN_DYNVARS_115_05-----------------------#' +############################################################################### +# Change the value of optimizer_use_condition_selectivity to an invalid value # +############################################################################## + +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.optimizer_use_condition_selectivity = ON; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.optimizer_use_condition_selectivity = OFF; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.optimizer_use_condition_selectivity = 65530.34; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.optimizer_use_condition_selectivity = test; + +--echo '#------------------FN_DYNVARS_115_06-----------------------#' +#################################################################### +# Check if the value in GLOBAL Table matches value in variable # +#################################################################### + + +SELECT @@global.optimizer_use_condition_selectivity = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='optimizer_use_condition_selectivity'; + +--echo '#------------------FN_DYNVARS_115_07-----------------------#' +#################################################################### +# Check if the value in SESSION Table matches value in variable # +#################################################################### + +SELECT @@session.optimizer_use_condition_selectivity = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_use_condition_selectivity'; + + +--echo '#---------------------FN_DYNVARS_115_08----------------------#' +############################################################################### +# Check if global and session variable are independent of each other # +############################################################################### + +SET @@optimizer_use_condition_selectivity = 1; +SET @@global.optimizer_use_condition_selectivity = 3; +SELECT @@optimizer_use_condition_selectivity = @@global.optimizer_use_condition_selectivity; + + +--echo '#---------------------FN_DYNVARS_115_09----------------------#' +############################################################################### +# Check if accessing variable with SESSION,LOCAL and without SCOPE points # +# to same session variable # +############################################################################### + +SET @@optimizer_use_condition_selectivity = 2; +SELECT @@optimizer_use_condition_selectivity = @@local.optimizer_use_condition_selectivity; +SELECT @@local.optimizer_use_condition_selectivity = @@session.optimizer_use_condition_selectivity; + + +#################################### +# Restore initial value # +#################################### + +SET @@global.optimizer_use_condition_selectivity = @start_global_value; +SELECT @@global.optimizer_use_condition_selectivity; +SET @@session.optimizer_use_condition_selectivity = @start_session_value; +SELECT @@session.optimizer_use_condition_selectivity; + +######################################################################## +# END OF optimizer_use_condition_selectivity TESTS # +######################################################################## + diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test new file mode 100644 index 00000000000..4756c6d4816 --- /dev/null +++ b/mysql-test/t/selectivity.test @@ -0,0 +1,65 @@ +--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'; + +--disable_warnings +DROP DATABASE IF EXISTS dbt3_s001; +--enable_warnings + +CREATE DATABASE dbt3_s001; + +use dbt3_s001; + +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; + +--disable_query_log +--disable_result_log +--disable_warnings +--source include/dbt3_s001.inc + +ANALYZE TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +FLUSH TABLE +customer, lineitem, nation, orders, part, partsupp, region, supplier; +--enable_warnings +--enable_result_log +--enable_query_log + +let $Q20= +select sql_calc_found_rows + s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp + where ps_partkey in (select p_partkey from part + where p_name like 'g%') + and ps_availqty > + (select 0.5 * sum(l_quantity) + from lineitem + where l_partkey = ps_partkey + and l_suppkey = ps_suppkey + and l_shipdate >= date('1993-01-01') + and l_shipdate < date('1993-01-01') + + interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; + +eval EXPLAIN EXTENDED $Q20; +eval $Q20; + +set optimizer_use_condition_selectivity=3; + +eval EXPLAIN EXTENDED $Q20; +eval $Q20; + +DROP DATABASE dbt3_s001; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/selectivity_innodb.test b/mysql-test/t/selectivity_innodb.test new file mode 100644 index 00000000000..6b67e2d0529 --- /dev/null +++ b/mysql-test/t/selectivity_innodb.test @@ -0,0 +1,12 @@ +--source include/have_innodb.inc + +SET SESSION STORAGE_ENGINE='InnoDB'; + +set @save_optimizer_switch_for_selectivity_test=@@optimizer_switch; +set optimizer_switch='extended_keys=on'; + +--source selectivity.test + +set optimizer_switch=@save_optimizer_switch_for_selectivity_test; + +SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/sql/field.cc b/sql/field.cc index d4468ba3c5b..e54a3e59795 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -1273,6 +1273,20 @@ out_of_range: return 1; } + +double Field_num::middle_point_pos(Field *min, Field *max) +{ + double n, d; + n= val_real() - min->val_real(); + if (n < 0) + return 0.0; + d= max->val_real() - min->val_real(); + if (d <= 0) + return 1.0; + return min(n/d, 1.0); +} + + /** Process decimal library return codes and issue warnings for overflow and truncation. @@ -1344,6 +1358,8 @@ Field::Field(uchar *ptr_arg,uint32 length_arg,uchar *null_ptr_arg, comment.length=0; field_index= 0; is_stat_field= FALSE; + cond_selectivity= 1.0; + next_equal_field= NULL; } @@ -6167,6 +6183,46 @@ int Field_str::store(double nr) return store(buff, length, &my_charset_numeric); } +static +inline ulonglong char_prefix_to_ulonglong(uchar *src) +{ + uint sz= sizeof(ulonglong); + for (uint i= 0; i < sz/2; i++) + { + uchar tmp= src[i]; + src[i]= src[sz-1-i]; + src[sz-1-i]= tmp; + } + return uint8korr(src); +} + +double Field_str::middle_point_pos(Field *min, Field *max) +{ + uchar mp_prefix[sizeof(ulonglong)]; + uchar minp_prefix[sizeof(ulonglong)]; + uchar maxp_prefix[sizeof(ulonglong)]; + ulonglong mp, minp, maxp; + my_strnxfrm(charset(), mp_prefix, sizeof(mp), + ptr + length_size(), sizeof(mp) * charset()->mbmaxlen); + my_strnxfrm(charset(), minp_prefix, sizeof(minp), + min->ptr + length_size(), + sizeof(minp) * charset()->mbmaxlen); + my_strnxfrm(charset(), maxp_prefix, sizeof(maxp), + max->ptr + length_size(), + sizeof(maxp) * charset()->mbmaxlen); + mp= char_prefix_to_ulonglong(mp_prefix); + minp= char_prefix_to_ulonglong(minp_prefix); + maxp= char_prefix_to_ulonglong(maxp_prefix); + double n, d; + n= mp - minp; + if (n < 0) + return 0.0; + d= maxp - minp; + if (d <= 0) + return 1.0; + return min(n/d, 1.0); +} + uint Field::is_equal(Create_field *new_field) { diff --git a/sql/field.h b/sql/field.h index e832928b114..40cbcca09ad 100644 --- a/sql/field.h +++ b/sql/field.h @@ -220,7 +220,23 @@ public: */ bool is_created_from_null_item; - bool is_stat_field; /* TRUE in Field objects created for column min/max values */ + /* TRUE in Field objects created for column min/max values */ + bool is_stat_field; + + /* + Selectivity of the range condition over this field. + When calculating this selectivity a range predicate + is taken into account only if: + - it is extracted from the WHERE clause + - it depends only on the table the field belongs to + */ + double cond_selectivity; + + /* + The next field in the class of equal fields at the top AND level + of the WHERE clause + */ + Field *next_equal_field; /* This structure is used for statistical data on the column @@ -703,6 +719,11 @@ public: virtual bool hash_join_is_possible() { return TRUE; } virtual bool eq_cmp_as_binary() { return TRUE; } + virtual double middle_point_pos(Field *min, Field *max) + { + return (double) 1.0; + } + friend int cre_myisam(char * name, register TABLE *form, uint options, ulonglong auto_increment_value); friend class Copy_field; @@ -821,6 +842,7 @@ public: bool get_int(CHARSET_INFO *cs, const char *from, uint len, longlong *rnd, ulonglong unsigned_max, longlong signed_min, longlong signed_max); + double middle_point_pos(Field *min, Field *max); }; @@ -866,6 +888,8 @@ public: virtual bool str_needs_quotes() { return TRUE; } uint is_equal(Create_field *new_field); bool eq_cmp_as_binary() { return test(flags & BINARY_FLAG); } + virtual uint length_size() { return 0; } + double middle_point_pos(Field *min, Field *max); }; /* base class for Field_string, Field_varstring and Field_blob */ @@ -1894,6 +1918,7 @@ public: uint new_null_bit); uint is_equal(Create_field *new_field); void hash(ulong *nr, ulong *nr2); + uint length_size() { return length_bytes; } private: int do_save_field_metadata(uchar *first_byte); }; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index b1208243e6b..b95cd2dbc90 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -5567,7 +5567,8 @@ Item *Item_bool_rowready_func2::negated_item() */ Item_equal::Item_equal(Item *f1, Item *f2, bool with_const_item) - : Item_bool_func(), eval_item(0), cond_false(0), context_field(NULL) + : Item_bool_func(), eval_item(0), cond_false(0), context_field(NULL), + link_equal_fields(FALSE) { const_item_cache= 0; with_const= with_const_item; @@ -5590,7 +5591,8 @@ Item_equal::Item_equal(Item *f1, Item *f2, bool with_const_item) */ Item_equal::Item_equal(Item_equal *item_equal) - : Item_bool_func(), eval_item(0), cond_false(0), context_field(NULL) + : Item_bool_func(), eval_item(0), cond_false(0), context_field(NULL), + link_equal_fields(FALSE) { const_item_cache= 0; List_iterator_fast li(item_equal->equal_items); @@ -5833,6 +5835,9 @@ bool Item_equal::fix_fields(THD *thd, Item **ref) DBUG_ASSERT(fixed == 0); Item_equal_fields_iterator it(*this); Item *item; + Field *first_equal_field; + Field *last_equal_field; + Field *prev_equal_field= NULL; not_null_tables_cache= used_tables_cache= 0; const_item_cache= 0; while ((item= it++)) @@ -5846,7 +5851,18 @@ bool Item_equal::fix_fields(THD *thd, Item **ref) maybe_null= 1; if (!item->get_item_equal()) item->set_item_equal(this); + if (link_equal_fields && item->real_item()->type() == FIELD_ITEM) + { + last_equal_field= ((Item_field *) (item->real_item()))->field; + if (!prev_equal_field) + first_equal_field= last_equal_field; + else + prev_equal_field->next_equal_field= last_equal_field; + prev_equal_field= last_equal_field; + } } + if (prev_equal_field && last_equal_field != first_equal_field) + last_equal_field->next_equal_field= first_equal_field; fix_length_and_dec(); fixed= 1; return FALSE; diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index 5a5f9ad60fd..5ac918895fa 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -1730,6 +1730,7 @@ class Item_equal: public Item_bool_func used in the original equality. */ Item_field *context_field; + bool link_equal_fields; public: inline Item_equal() : Item_bool_func(), with_const(FALSE), eval_item(0), cond_false(0), @@ -1762,6 +1763,7 @@ public: CHARSET_INFO *compare_collation(); void set_context_field(Item_field *ctx_field) { context_field= ctx_field; } + void set_link_equal_fields(bool flag) { link_equal_fields= flag; } friend class Item_equal_fields_iterator; friend Item *eliminate_item_equal(COND *cond, COND_EQUAL *upper_levels, Item_equal *item_equal); diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 7a3a0c94a18..364b01aebb2 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -117,6 +117,7 @@ #include "records.h" // init_read_record, end_read_record #include #include "sql_select.h" +#include "sql_statistics.h" #include "filesort.h" // filesort_free_buffers #ifndef EXTRA_DEBUG @@ -3211,6 +3212,224 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use, DBUG_RETURN(records ? test(quick) : -1); } +/**************************************************************************** + * Condition selectivity module + ****************************************************************************/ + +static +bool create_key_parts_for_pseudo_indexes(RANGE_OPT_PARAM *param, + MY_BITMAP *used_fields) +{ + Field **field_ptr; + TABLE *table= param->table; + uint parts= 0; + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + if (bitmap_is_set(used_fields, (*field_ptr)->field_index)) + parts++; + } + + KEY_PART *key_part; + uint keys= 0; + + if (!(key_part= (KEY_PART *) alloc_root(param->mem_root, + sizeof(KEY_PART) * parts))) + return TRUE; + + param->key_parts= key_part; + + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + if (bitmap_is_set(used_fields, (*field_ptr)->field_index)) + { + Field *field= *field_ptr; + uint16 store_length; + key_part->key= keys; + key_part->part= 0; + key_part->length= (uint16) field->key_length(); + store_length= key_part->length; + if (field->real_maybe_null()) + store_length+= HA_KEY_NULL_LENGTH; + if (field->real_type() == MYSQL_TYPE_VARCHAR) + store_length+= HA_KEY_BLOB_LENGTH; + key_part->store_length= store_length; + key_part->field= field; + key_part->image_type= Field::itRAW; + param->key[keys]= key_part; + keys++; + key_part++; + } + } + param->keys= keys; + param->key_parts_end= key_part; + + return FALSE; +} + + +static +double records_in_column_ranges(PARAM *param, uint idx, + SEL_ARG *tree) +{ + SEL_ARG_RANGE_SEQ seq; + KEY_MULTI_RANGE range; + range_seq_t seq_it; + double rows; + Field *field; + uint flags= 0; + double total_rows= 0; + RANGE_SEQ_IF seq_if = {NULL, sel_arg_range_seq_init, + sel_arg_range_seq_next, 0, 0}; + + /* Handle cases when we don't have a valid non-empty list of range */ + if (!tree) + return HA_POS_ERROR; + if (tree->type == SEL_ARG::IMPOSSIBLE) + return (0L); + + field= tree->field; + + seq.keyno= idx; + seq.real_keyno= MAX_KEY; + seq.param= param; + seq.start= tree; + + seq_it= seq_if.init((void *) &seq, 0, flags); + + while (!seq_if.next(seq_it, &range)) + { + key_range *min_endp, *max_endp; + min_endp= range.start_key.length? &range.start_key : NULL; + max_endp= range.end_key.length? &range.end_key : NULL; + rows= get_column_range_cardinality(field, min_endp, max_endp); + if (HA_POS_ERROR == rows) + { + total_rows= HA_POS_ERROR; + break; + } + total_rows += rows; + } + return total_rows; +} + + +bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) +{ + uint keynr; + uint max_quick_key_parts= 0; + MY_BITMAP *used_fields= &table->cond_set; + double table_records= table->stat_records(); + DBUG_ENTER("calculate_cond_selectivity_for_table"); + + table->cond_selectivity= 1.0; + + if (bitmap_is_clear_all(used_fields)) + DBUG_RETURN(FALSE); + + PARAM param; + MEM_ROOT alloc; + init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, + MYF(MY_THREAD_SPECIFIC)); + param.thd= thd; + param.mem_root= &alloc; + param.old_root= thd->mem_root; + param.table= table; + param.is_ror_scan= FALSE; + + if (create_key_parts_for_pseudo_indexes(¶m, used_fields)) + { + free_root(&alloc, MYF(0)); + DBUG_RETURN(FALSE); + } + + param.prev_tables= param.read_tables= 0; + param.current_table= table->map; + param.using_real_indexes= FALSE; + param.real_keynr[0]= 0; + param.alloced_sel_args= 0; + + thd->no_errors=1; // Don't warn about NULL + + SEL_TREE *tree; + SEL_ARG **key, **end; + uint idx= 0; + + tree= get_mm_tree(¶m, cond); + + if (!tree) + goto end; + + + for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) + { + double rows; + if (*key) + { + rows= records_in_column_ranges(¶m, idx, *key); + if (rows != HA_POS_ERROR) + (*key)->field->cond_selectivity= rows/table_records; + } + } + + 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) && + table_field->cond_selectivity < 1.0) + table->cond_selectivity*= table_field->cond_selectivity; + } + + /* Calculate the selectivity of the range conditions supported by indexes */ + + bitmap_clear_all(used_fields); + + for (keynr= 0; keynr < table->s->keys; keynr++) + { + if (table->quick_keys.is_set(keynr)) + set_if_bigger(max_quick_key_parts, table->quick_key_parts[keynr]); + } + + for (uint quick_key_parts= max_quick_key_parts; + quick_key_parts; quick_key_parts--) + { + for (keynr= 0; keynr < table->s->keys; keynr++) + { + if (table->quick_keys.is_set(keynr) && + table->quick_key_parts[keynr] == quick_key_parts) + { + uint i; + uint used_key_parts= table->quick_key_parts[keynr]; + double quick_cond_selectivity= table->quick_rows[keynr] / + table_records; + KEY *key_info= table->key_info + keynr; + KEY_PART_INFO* key_part= key_info->key_part; + for (i= 0; i < used_key_parts; i++, key_part++) + { + if (bitmap_is_set(used_fields, key_part->fieldnr-1)) + break; + bitmap_set_bit(used_fields, key_part->fieldnr-1); + } + if (i) + { + double f1= key_info->actual_rec_per_key(i-1); + double f2= key_info->actual_rec_per_key(i); + table->cond_selectivity*= quick_cond_selectivity * f1 / f2; + } + } + } + } + +end: + thd->mem_root= param.old_root; + free_root(&alloc, MYF(0)); + DBUG_RETURN(FALSE); +} + +/**************************************************************************** + * Condition selectivity code ends + ****************************************************************************/ + /**************************************************************************** * Partition pruning module ****************************************************************************/ diff --git a/sql/opt_range.h b/sql/opt_range.h index c59b2a7eb02..484f508e49c 100644 --- a/sql/opt_range.h +++ b/sql/opt_range.h @@ -1042,6 +1042,8 @@ SQL_SELECT *make_select(TABLE *head, table_map const_tables, table_map read_tables, COND *conds, bool allow_null_cond, int *error); +bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond); + #ifdef WITH_PARTITION_STORAGE_ENGINE bool prune_partitions(THD *thd, TABLE *table, Item *pprune_cond); void store_key_image_to_rec(Field *field, uchar *ptr, uint len); diff --git a/sql/opt_range_mrr.cc b/sql/opt_range_mrr.cc index 1f4e36178db..8029dbf000f 100644 --- a/sql/opt_range_mrr.cc +++ b/sql/opt_range_mrr.cc @@ -268,8 +268,10 @@ walk_up_n_right: range->end_key.keypart_map= make_prev_keypart_map(cur->max_key_parts); if (!(cur->min_key_flag & ~NULL_RANGE) && !cur->max_key_flag && - (uint)key_tree->part+1 == seq->param->table->key_info[seq->real_keyno].key_parts && - (seq->param->table->key_info[seq->real_keyno].flags & HA_NOSAME) && + (seq->real_keyno == MAX_KEY || + ((uint)key_tree->part+1 == + seq->param->table->key_info[seq->real_keyno].key_parts && + (seq->param->table->key_info[seq->real_keyno].flags & HA_NOSAME))) && range->start_key.length == range->end_key.length && !memcmp(seq->param->min_key,seq->param->max_key,range->start_key.length)) range->range_flag= UNIQUE_RANGE | (cur->min_key_flag & NULL_RANGE); diff --git a/sql/opt_subselect.cc b/sql/opt_subselect.cc index 6698d4af28d..36ab3a9a2e0 100644 --- a/sql/opt_subselect.cc +++ b/sql/opt_subselect.cc @@ -3889,7 +3889,7 @@ SJ_TMP_TABLE::create_sj_weedout_tmp_table(THD *thd) &tmpname, (uint) strlen(path)+1, &group_buff, (!using_unique_constraint ? uniq_tuple_length_arg : 0), - &bitmaps, bitmap_buffer_size(1)*3, + &bitmaps, bitmap_buffer_size(1)*5, NullS)) { if (temp_pool_slot != MY_BIT_NONE) diff --git a/sql/opt_subselect.h b/sql/opt_subselect.h index 7b8f3142851..508531b8c37 100644 --- a/sql/opt_subselect.h +++ b/sql/opt_subselect.h @@ -283,6 +283,7 @@ public: { pos->records_read= best_loose_scan_records; pos->key= best_loose_scan_start_key; + pos->cond_selectivity= 1.0; pos->loosescan_picker.loosescan_key= best_loose_scan_key; pos->loosescan_picker.loosescan_parts= best_max_loose_keypart + 1; pos->use_join_buffer= FALSE; diff --git a/sql/sql_class.h b/sql/sql_class.h index 87b9783c1ed..e2fe3a53dcc 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -499,6 +499,7 @@ typedef struct system_variables ulong net_write_timeout; ulong optimizer_prune_level; ulong optimizer_search_depth; + ulong optimizer_use_condition_selectivity; ulong use_stat_tables; ulong preload_buff_size; ulong profiling_history_size; diff --git a/sql/sql_priv.h b/sql/sql_priv.h index 4e356b48497..d14ec5d0983 100644 --- a/sql/sql_priv.h +++ b/sql/sql_priv.h @@ -228,6 +228,7 @@ template bool valid_buffer_range(T jump, #define OPTIMIZER_SWITCH_TABLE_ELIMINATION (1ULL << 26) #define OPTIMIZER_SWITCH_EXTENDED_KEYS (1ULL << 27) #define OPTIMIZER_SWITCH_EXISTS_TO_IN (1ULL << 28) +#define OPTIMIZER_SWITCH_USE_CONDITION_SELECTIVITY (1ULL << 29) #define OPTIMIZER_SWITCH_DEFAULT (OPTIMIZER_SWITCH_INDEX_MERGE | \ OPTIMIZER_SWITCH_INDEX_MERGE_UNION | \ diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 81f510a4563..bc9e05fe2d9 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -89,12 +89,14 @@ void best_access_path(JOIN *join, JOIN_TAB *s, POSITION *pos, POSITION *loose_scan_pos); static void optimize_straight_join(JOIN *join, table_map join_tables); static bool greedy_search(JOIN *join, table_map remaining_tables, - uint depth, uint prune_level); + uint depth, uint prune_level, + uint use_cond_selectivity); static bool best_extension_by_limited_search(JOIN *join, table_map remaining_tables, uint idx, double record_count, double read_time, uint depth, - uint prune_level); + uint prune_level, + uint use_cond_selectivity); static uint determine_search_depth(JOIN* join); C_MODE_START static int join_tab_cmp(const void *dummy, const void* ptr1, const void* ptr2); @@ -133,7 +135,8 @@ static int return_zero_rows(JOIN *join, select_result *res, static COND *build_equal_items(THD *thd, COND *cond, COND_EQUAL *inherited, List *join_list, - COND_EQUAL **cond_equal_ref); + COND_EQUAL **cond_equal_ref, + bool link_equal_fields= FALSE); static COND* substitute_for_best_equal_field(JOIN_TAB *context_tab, COND *cond, COND_EQUAL *cond_equal, @@ -149,7 +152,8 @@ static uint build_bitmap_for_nested_joins(List *join_list, static COND *optimize_cond(JOIN *join, COND *conds, List *join_list, Item::cond_result *cond_value, - COND_EQUAL **cond_equal); + COND_EQUAL **cond_equal, + int flags= 0); bool const_expression_in_where(COND *conds,Item *item, Item **comp_item); static bool create_internal_tmp_table_from_heap2(THD *, TABLE *, ENGINE_COLUMNDEF *, ENGINE_COLUMNDEF **, @@ -277,6 +281,8 @@ enum enum_exec_or_opt {WALK_OPTIMIZATION_TABS , WALK_EXECUTION_TABS}; JOIN_TAB *first_breadth_first_tab(JOIN *join, enum enum_exec_or_opt tabs_kind); JOIN_TAB *next_breadth_first_tab(JOIN *join, enum enum_exec_or_opt tabs_kind, JOIN_TAB *tab); +static double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, + table_map rem_tables); #ifndef DBUG_OFF @@ -1155,7 +1161,8 @@ TODO: make view to decide if it is possible to write to WHERE directly or make S if (setup_jtbm_semi_joins(this, join_list, &conds)) DBUG_RETURN(1); - conds= optimize_cond(this, conds, join_list, &cond_value, &cond_equal); + conds= optimize_cond(this, conds, join_list, &cond_value, &cond_equal, + OPT_LINK_EQUAL_FIELDS); if (thd->is_error()) { @@ -3350,6 +3357,7 @@ make_join_statistics(JOIN *join, List &tables_list, table->pos_in_table_list= tables; error= tables->fetch_number_of_rows(); set_statistics_for_table(join->thd, table); + bitmap_clear_all(&table->cond_set); #ifdef WITH_PARTITION_STORAGE_ENGINE const bool no_partitions_used= table->no_partitions_used; @@ -3837,6 +3845,11 @@ make_join_statistics(JOIN *join, List &tables_list, } delete select; } + + if (join->thd->variables.optimizer_use_condition_selectivity > 1) + calculate_cond_selectivity_for_table(join->thd, s->table, + *s->on_expr_ref ? + *s->on_expr_ref : conds); } if (pull_out_semijoin_tables(join)) @@ -4190,11 +4203,12 @@ add_key_field(JOIN *join, else if (!(field->flags & PART_KEY_FLAG)) { // Don't remove column IS NULL on a LEFT JOIN table - if (!eq_func || (*value)->type() != Item::NULL_ITEM || - !field->table->maybe_null || field->null_ptr) - return; // Not a key. Skip it - optimize= KEY_OPTIMIZE_EXISTS; - DBUG_ASSERT(num_values == 1); + if (eq_func && (*value)->type() == Item::NULL_ITEM && + field->table->maybe_null && !field->null_ptr) + { + optimize= KEY_OPTIMIZE_EXISTS; + DBUG_ASSERT(num_values == 1); + } } if (optimize != KEY_OPTIMIZE_EXISTS) { @@ -4243,7 +4257,11 @@ add_key_field(JOIN *join, break; } if (is_const) + { stat[0].const_keys.merge(possible_keys); + if (possible_keys.is_clear_all()) + bitmap_set_bit(&field->table->cond_set, field->field_index); + } else if (!eq_func) { /* @@ -5313,6 +5331,7 @@ void set_position(JOIN *join,uint idx,JOIN_TAB *table,KEYUSE *key) join->positions[idx].table= table; join->positions[idx].key=key; join->positions[idx].records_read=1.0; /* This is a const table */ + join->positions[idx].cond_selectivity= 1.0; join->positions[idx].ref_depend_map= 0; // join->positions[idx].loosescan_key= MAX_KEY; /* Not a LooseScan */ @@ -6127,6 +6146,8 @@ choose_plan(JOIN *join, table_map join_tables) { uint search_depth= join->thd->variables.optimizer_search_depth; uint prune_level= join->thd->variables.optimizer_prune_level; + uint use_cond_selectivity= + join->thd->variables.optimizer_use_condition_selectivity; bool straight_join= test(join->select_options & SELECT_STRAIGHT_JOIN); DBUG_ENTER("choose_plan"); @@ -6191,7 +6212,8 @@ choose_plan(JOIN *join, table_map join_tables) if (search_depth == 0) /* Automatically determine a reasonable value for 'search_depth' */ search_depth= determine_search_depth(join); - if (greedy_search(join, join_tables, search_depth, prune_level)) + if (greedy_search(join, join_tables, search_depth, prune_level, + use_cond_selectivity)) DBUG_RETURN(TRUE); } } @@ -6465,6 +6487,8 @@ optimize_straight_join(JOIN *join, table_map join_tables) bool disable_jbuf= join->thd->variables.join_cache_level == 0; double record_count= 1.0; double read_time= 0.0; + uint use_cond_selectivity= + join->thd->variables.optimizer_use_condition_selectivity; POSITION loose_scan_pos; for (JOIN_TAB **pos= join->best_ref + idx ; (s= *pos) ; pos++) @@ -6481,6 +6505,11 @@ optimize_straight_join(JOIN *join, table_map join_tables) &loose_scan_pos); join_tables&= ~(s->table->map); + double pushdown_cond_selectivity= 1.0; + if (use_cond_selectivity > 1) + pushdown_cond_selectivity= table_cond_selectivity(join, idx, s, + join_tables); + join->positions[idx].cond_selectivity= pushdown_cond_selectivity; ++idx; } @@ -6568,6 +6597,8 @@ optimize_straight_join(JOIN *join, table_map join_tables) @param search_depth controlls the exhaustiveness of the search @param prune_level the pruning heuristics that should be applied during search + @param use_cond_selectivity specifies how the selectivity of the conditions + pushed to a table should be taken into account @retval FALSE ok @@ -6579,7 +6610,8 @@ static bool greedy_search(JOIN *join, table_map remaining_tables, uint search_depth, - uint prune_level) + uint prune_level, + uint use_cond_selectivity) { double record_count= 1.0; double read_time= 0.0; @@ -6604,7 +6636,8 @@ greedy_search(JOIN *join, /* Find the extension of the current QEP with the lowest cost */ join->best_read= DBL_MAX; if (best_extension_by_limited_search(join, remaining_tables, idx, record_count, - read_time, search_depth, prune_level)) + read_time, search_depth, prune_level, + use_cond_selectivity)) DBUG_RETURN(TRUE); /* 'best_read < DBL_MAX' means that optimizer managed to find @@ -6843,6 +6876,158 @@ double JOIN::get_examined_rows() } +static +double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, + table_map rem_tables, TABLE_REF *ref) +{ + double sel= 1.0; + COND_EQUAL *cond_equal= join->cond_equal; + + if (!cond_equal || !cond_equal->current_level.elements) + return sel; + + Item_equal *item_equal; + List_iterator_fast it(cond_equal->current_level); + table_map table_bit= s->table->map; + + if (!s->keyuse) + return sel; + + KEY *key_info= s->get_keyinfo_by_key_no(s->ref.key); + + while ((item_equal= it++)) + { + /* + Check whether we need to take into account the selectivity of + multiple equality item_equal. If this is the case multiply + the current value of sel by this selectivity + */ + table_map used_tables= item_equal->used_tables(); + if (!(used_tables & table_bit)) + continue; + if (item_equal->get_const()) + continue; + + Field *fld; + bool adjust_sel= FALSE; + Item_equal_fields_iterator fi(*item_equal); + while((fi++) && !adjust_sel) + { + Field *fld= fi.get_curr_field(); + if (fld->table->map != table_bit) + continue; + if (ref == 0) + adjust_sel= TRUE; + else + { + uint i; + for (i= 0; i < ref->key_parts; i++) + { + if (fld->field_index == key_info->key_part[i].fieldnr - 1) + break; + } + if (i == ref->key_parts) + { + /* + Field fld is included in multiple equality item_equal + and is not a part of the ref key. + The selectivity of the multiple equality must be taken + into account unless one of the ref arguments is + equal to fld. + */ + adjust_sel= TRUE; + for (uint j= 0; j < ref->key_parts && adjust_sel; j++) + { + if (ref->items[j]->real_item()->type() == Item::FIELD_ITEM) + { + Item_field *field_item= (Item_field *) (ref->items[j]); + if (item_equal->contains(field_item->field)) + adjust_sel= FALSE; + } + } + } + } + } + if (adjust_sel) + { + /* + If ref == 0 and there are no fields in the multiple equality + item_equal that belong to the tables joined prior to s + then the selectivity of multiple equality will be set to 1.0. + */ + double eq_fld_sel= 1.0; + fi.rewind(); + while ((fi++)) + { + double curr_eq_fld_sel; + fld= fi.get_curr_field(); + if (!fld->table->map & ~(table_bit | rem_tables)) + continue; + curr_eq_fld_sel= get_column_avg_frequency(fld) / + fld->table->stat_records(); + if (curr_eq_fld_sel < 1.0) + set_if_bigger(eq_fld_sel, curr_eq_fld_sel); + } + sel*= eq_fld_sel; + } + } + return sel; +} + +static +double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, + table_map rem_tables) +{ + Field *field; + TABLE *table= s->table; + MY_BITMAP *read_set= table->read_set; + double sel= s->table->cond_selectivity; + double table_records= table->stat_records(); + TABLE_REF *ref= s->type == JT_REF || s->type == JT_EQ_REF ? &s->ref : NULL; + + /* Discount the selectivity of the access method used to join table s */ + if (s->quick && s->quick->index != MAX_KEY) + { + /* A range scan by index s->quick->index is used to access table s */ + sel*= table_records/table->quick_rows[s->quick->index]; + } + else if (ref) + { + /* A ref/ access or hash join is used to join table s */ + KEY *key_info= s->get_keyinfo_by_key_no(ref->key); + for (uint i= 0; i < ref->key_parts; i++) + { + if (ref->items[i]->const_item()) + { + uint fldno= key_info->key_part[i].fieldnr - 1; + sel*= table->field[fldno]->cond_selectivity; + } + } + } + + for (Field **f_ptr=table->field ; (field= *f_ptr) ; f_ptr++) + { + if (!bitmap_is_set(read_set, field->field_index) || + !field->next_equal_field) + continue; + for (Field *next_field= field->next_equal_field; + next_field != field; + next_field= next_field->next_equal_field) + { + if (!(next_field->table->map & rem_tables) && next_field->table != table) + { + sel/= field->cond_selectivity; + break; + } + } + } + + sel*= table_multi_eq_cond_selectivity(join, idx, s, rem_tables, ref); + + return sel; +} + + /** Find a good, possibly optimal, query execution plan (QEP) by a possibly exhaustive search. @@ -6953,6 +7138,8 @@ double JOIN::get_examined_rows() @param prune_level pruning heuristics that should be applied during optimization (values: 0 = EXHAUSTIVE, 1 = PRUNE_BY_TIME_OR_ROWS) + @param use_cond_selectivity specifies how the selectivity of the conditions + pushed to a table should be taken into account @retval FALSE ok @@ -6967,7 +7154,8 @@ best_extension_by_limited_search(JOIN *join, double record_count, double read_time, uint search_depth, - uint prune_level) + uint prune_level, + uint use_cond_selectivity) { DBUG_ENTER("best_extension_by_limited_search"); @@ -7070,16 +7258,25 @@ best_extension_by_limited_search(JOIN *join, } } + double pushdown_cond_selectivity= 1.0; + if (use_cond_selectivity > 1) + pushdown_cond_selectivity= table_cond_selectivity(join, idx, s, + remaining_tables & + ~real_table_bit); + join->positions[idx].cond_selectivity= pushdown_cond_selectivity; + double partial_join_cardinality= current_record_count * + pushdown_cond_selectivity; if ( (search_depth > 1) && (remaining_tables & ~real_table_bit) & allowed_tables ) { /* Recursively expand the current partial plan */ swap_variables(JOIN_TAB*, join->best_ref[idx], *pos); if (best_extension_by_limited_search(join, remaining_tables & ~real_table_bit, idx + 1, - current_record_count, + partial_join_cardinality, current_read_time, search_depth - 1, - prune_level)) + prune_level, + use_cond_selectivity)) DBUG_RETURN(TRUE); swap_variables(JOIN_TAB*, join->best_ref[idx], *pos); } @@ -7097,7 +7294,7 @@ best_extension_by_limited_search(JOIN *join, { memcpy((uchar*) join->best_positions, (uchar*) join->positions, sizeof(POSITION) * (idx + 1)); - join->record_count= current_record_count; + join->record_count= partial_join_cardinality; join->best_read= current_read_time - 0.001; } DBUG_EXECUTE("opt", print_plan(join, idx+1, @@ -7742,6 +7939,7 @@ get_best_combination(JOIN *join) */ SJ_MATERIALIZATION_INFO *sjm= cur_pos->table->emb_sj_nest->sj_mat_info; j->records= j->records_read= (ha_rows)(sjm->is_sj_scan? sjm->rows : 1); + j->cond_selectivity= 1.0; JOIN_TAB *jt; JOIN_TAB_RANGE *jt_range; if (!(jt= (JOIN_TAB*)join->thd->alloc(sizeof(JOIN_TAB)*sjm->tables)) || @@ -7805,6 +8003,7 @@ get_best_combination(JOIN *join) to access join->best_positions[]. */ j->records_read= (ha_rows)join->best_positions[tablenr].records_read; + j->cond_selectivity= join->best_positions[tablenr].cond_selectivity; join->map2table[j->table->tablenr]= j; /* If we've reached the end of sjm nest, switch back to main sequence */ @@ -11779,7 +11978,8 @@ static bool check_equality(THD *thd, Item *item, COND_EQUAL *cond_equal, */ static COND *build_equal_items_for_cond(THD *thd, COND *cond, - COND_EQUAL *inherited) + COND_EQUAL *inherited, + bool link_item_fields) { Item_equal *item_equal; COND_EQUAL cond_equal; @@ -11826,6 +12026,7 @@ static COND *build_equal_items_for_cond(THD *thd, COND *cond, List_iterator_fast it(cond_equal.current_level); while ((item_equal= it++)) { + item_equal->set_link_equal_fields(link_item_fields); item_equal->fix_fields(thd, NULL); item_equal->update_used_tables(); set_if_bigger(thd->lex->current_select->max_equal_elems, @@ -11843,7 +12044,8 @@ static COND *build_equal_items_for_cond(THD *thd, COND *cond, while ((item= li++)) { Item *new_item; - if ((new_item= build_equal_items_for_cond(thd, item, inherited)) != item) + if ((new_item= build_equal_items_for_cond(thd, item, inherited, FALSE)) + != item) { /* This replacement happens only for standalone equalities */ /* @@ -12000,13 +12202,14 @@ static COND *build_equal_items_for_cond(THD *thd, COND *cond, static COND *build_equal_items(THD *thd, COND *cond, COND_EQUAL *inherited, List *join_list, - COND_EQUAL **cond_equal_ref) + COND_EQUAL **cond_equal_ref, + bool link_equal_fields) { COND_EQUAL *cond_equal= 0; if (cond) { - cond= build_equal_items_for_cond(thd, cond, inherited); + cond= build_equal_items_for_cond(thd, cond, inherited, link_equal_fields); cond->update_used_tables(); if (cond->type() == Item::COND_ITEM && ((Item_cond*) cond)->functype() == Item_func::COND_AND_FUNC) @@ -13454,7 +13657,8 @@ void optimize_wo_join_buffering(JOIN *join, uint first_tab, uint last_tab, static COND * optimize_cond(JOIN *join, COND *conds, List *join_list, - Item::cond_result *cond_value, COND_EQUAL **cond_equal) + Item::cond_result *cond_value, COND_EQUAL **cond_equal, + int flags) { THD *thd= join->thd; DBUG_ENTER("optimize_cond"); @@ -13475,8 +13679,9 @@ optimize_cond(JOIN *join, COND *conds, List *join_list, multiple equality contains a constant. */ DBUG_EXECUTE("where", print_where(conds, "original", QT_ORDINARY);); - conds= build_equal_items(join->thd, conds, NULL, join_list, cond_equal); - DBUG_EXECUTE("where",print_where(conds,"after equal_items", QT_ORDINARY);); + conds= build_equal_items(join->thd, conds, NULL, join_list, cond_equal, + test(flags & OPT_LINK_EQUAL_FIELDS)); + DBUG_EXECUTE("where",print_where(conds,"after equal_items", QT_ORDINARY);); /* change field = field to field = const for each found field = const */ propagate_cond_constants(thd, (I_List *) 0, conds, conds); @@ -14258,6 +14463,9 @@ void setup_tmp_table_column_bitmaps(TABLE *table, uchar *bitmaps) bitmap_init(&table->eq_join_set, (my_bitmap_map*) (bitmaps+ 3*bitmap_buffer_size(field_count)), field_count, FALSE); + bitmap_init(&table->cond_set, + (my_bitmap_map*) (bitmaps+ 4*bitmap_buffer_size(field_count)), + field_count, FALSE); /* write_set and all_set are copies of read_set */ table->def_write_set= table->def_read_set; table->s->all_set= table->def_read_set; @@ -14421,7 +14629,7 @@ create_tmp_table(THD *thd, TMP_TABLE_PARAM *param, List &fields, &tmpname, (uint) strlen(path)+1, &group_buff, (group && ! using_unique_constraint ? param->group_length : 0), - &bitmaps, bitmap_buffer_size(field_count)*4, + &bitmaps, bitmap_buffer_size(field_count)*5, NullS)) { if (temp_pool_slot != MY_BIT_NONE) @@ -15176,7 +15384,7 @@ TABLE *create_virtual_tmp_table(THD *thd, List &field_list) &share, sizeof(*share), &field, (field_count + 1) * sizeof(Field*), &blob_field, (field_count+1) *sizeof(uint), - &bitmaps, bitmap_buffer_size(field_count)*4, + &bitmaps, bitmap_buffer_size(field_count)*5, NullS)) return 0; @@ -22068,7 +22276,13 @@ int JOIN::print_explain(select_result_sink *result, uint8 explain_flags, { float f= 0.0; if (examined_rows) - f= (float) (100.0 * tab->records_read / examined_rows); + { + double pushdown_cond_selectivity= tab->cond_selectivity; + if (pushdown_cond_selectivity == 1.0) + f= (float) (100.0 * tab->records_read / examined_rows); + else + f= (float) (100.0 * pushdown_cond_selectivity); + } set_if_smaller(f, 100.0); item_list.push_back(new Item_float(f, 2)); } diff --git a/sql/sql_select.h b/sql/sql_select.h index 638de926d75..87c09611009 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -292,6 +292,8 @@ typedef struct st_join_table { /* psergey-todo: make the below have type double, like POSITION::records_read? */ ha_rows records_read; + double cond_selectivity; + /* Startup cost for execution */ double startup_cost; @@ -762,6 +764,8 @@ typedef struct st_position :public Sql_alloc */ double records_read; + double cond_selectivity; + /* Cost accessing the table in course of the entire complete join execution, i.e. cost of one access method use (e.g. 'range' or 'ref' scan ) times @@ -1804,6 +1808,8 @@ void eliminate_tables(JOIN *join); /* Index Condition Pushdown entry point function */ void push_index_cond(JOIN_TAB *tab, uint keyno); +#define OPT_LINK_EQUAL_FIELDS 1 + /**************************************************************************** Temporary table support for SQL Runtime ***************************************************************************/ diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index e34b4b21819..5338632067a 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 "opt_range.h" #include "my_atomic.h" /* @@ -3054,3 +3055,51 @@ void set_statistics_for_table(THD *thd, TABLE *table) key_info->read_stats->get_avg_frequency(0) > 0.5); } } + + +double get_column_avg_frequency(Field * field) +{ + double res; + TABLE *table= field->table; + Column_statistics *col_stats= table->s->field[field->field_index]->read_stats; + + if (!col_stats) + res= table->stat_records(); + else + res= col_stats->get_avg_frequency(); + return res; +} + + +double get_column_range_cardinality(Field *field, + key_range *min_endp, + key_range *max_endp) +{ + double res; + TABLE *table= field->table; + Column_statistics *col_stats= table->field[field->field_index]->read_stats; + + if (!col_stats) + res= table->stat_records(); + else if (min_endp->length == max_endp->length && + !memcmp(min_endp->key, max_endp->key, min_endp->length)) + { + res= col_stats->get_avg_frequency(); + } + else + { + if (col_stats->min_value && col_stats->max_value) + { + store_key_image_to_rec(field, (uchar *) min_endp->key, min_endp->length); + double min_mp_pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + store_key_image_to_rec(field, (uchar *) max_endp->key, max_endp->length); + double max_mp_pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + res= table->stat_records() * (max_mp_pos - min_mp_pos); + } + else + res= table->stat_records(); + } + return res; +} diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 17f22cec4e5..6bf552b92a0 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -90,6 +90,12 @@ 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); +double get_column_avg_frequency(Field * field); + +double get_column_range_cardinality(Field *field, + key_range *min_endp, + key_range *max_endp); + class Columns_statistics; class Index_statistics; diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index fcd2df7b338..7f6a00f3c62 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -1424,6 +1424,22 @@ static Sys_var_ulong Sys_optimizer_prune_level( SESSION_VAR(optimizer_prune_level), CMD_LINE(REQUIRED_ARG), VALID_RANGE(0, 1), DEFAULT(1), BLOCK_SIZE(1)); +static Sys_var_ulong Sys_optimizer_use_condition_selectivity( + "optimizer_use_condition_selectivity", + "Controls selectivity of which conditions the optimizer takes into " + "account to calculate cardinality of a partial join when it searches " + "for the best execution plan " + "Meaning: " + "1 - use selectivity of index backed range conditions to calculate " + "cardinality of the partial join if the last joined table is " + "accessed by full table scan or an index scan " + "2 - use selectivity of index backed range conditions to calculate " + "cardinality of the partial join in any case " + "3 - additionally always use selectivity of range conditions that are " + "not backed by any index to calculate cardinality of the partial join", + SESSION_VAR(optimizer_use_condition_selectivity), CMD_LINE(REQUIRED_ARG), + VALID_RANGE(1, 3), DEFAULT(1), BLOCK_SIZE(1)); + /** Warns about deprecated value 63 */ static bool fix_optimizer_search_depth(sys_var *self, THD *thd, enum_var_type type) diff --git a/sql/table.cc b/sql/table.cc index a011fa845a7..e4dc2adef64 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -2630,7 +2630,7 @@ partititon_err: /* Allocate bitmaps */ bitmap_size= share->column_bitmap_size; - if (!(bitmaps= (uchar*) alloc_root(&outparam->mem_root, bitmap_size*5))) + if (!(bitmaps= (uchar*) alloc_root(&outparam->mem_root, bitmap_size*6))) goto err; bitmap_init(&outparam->def_read_set, (my_bitmap_map*) bitmaps, share->fields, FALSE); @@ -2642,8 +2642,12 @@ partititon_err: (my_bitmap_map*) (bitmaps+bitmap_size*3), share->fields, FALSE); bitmap_init(&outparam->eq_join_set, (my_bitmap_map*) (bitmaps+bitmap_size*4), share->fields, FALSE); + bitmap_init(&outparam->cond_set, + (my_bitmap_map*) (bitmaps+bitmap_size*5), share->fields, FALSE); outparam->default_column_bitmaps(); + outparam->cond_selectivity= 1.0; + /* The table struct is now initialized; Open the table */ error= 2; if (db_stat) diff --git a/sql/table.h b/sql/table.h index 1a567ae75d1..85b31af8a77 100644 --- a/sql/table.h +++ b/sql/table.h @@ -1026,6 +1026,7 @@ public: my_bitmap_map *bitmap_init_value; MY_BITMAP def_read_set, def_write_set, def_vcol_set, tmp_set; MY_BITMAP eq_join_set; /* used to mark equi-joined fields */ + MY_BITMAP cond_set; /* used to mark fields from sargable conditions*/ MY_BITMAP *read_set, *write_set, *vcol_set; /* Active column sets */ /* The ID of the query that opened and is using this table. Has different @@ -1078,6 +1079,8 @@ public: */ ha_rows quick_condition_rows; + double cond_selectivity; + table_map map; /* ID bit of table (1,2,4,8,16...) */ uint lock_position; /* Position in MYSQL_LOCK.table */ From aab3c9febc37fdf8b29d6a484d8f3f48a29dd92d Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sun, 17 Mar 2013 12:02:11 -0700 Subject: [PATCH 02/37] Fixed a typo that caused a wrong calculation of the selectivity for pushed down condtions. --- mysql-test/r/selectivity.result | 2 +- mysql-test/r/selectivity_innodb.result | 2 +- sql/sql_select.cc | 2 +- 3 files changed, 3 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 3db8da46ea2..9d38bd3c976 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -84,7 +84,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where -4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 0a6abfd66d3..18cd35f2892 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -87,7 +87,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where -4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 diff --git a/sql/sql_select.cc b/sql/sql_select.cc index bc9e05fe2d9..b6e21a3b8a9 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6989,7 +6989,7 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, if (s->quick && s->quick->index != MAX_KEY) { /* A range scan by index s->quick->index is used to access table s */ - sel*= table_records/table->quick_rows[s->quick->index]; + sel*= table->quick_rows[s->quick->index]/table_records; } else if (ref) { From 8ab81843cd5afef3a2905d9c802168a048de35c7 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 20 Mar 2013 01:00:25 -0700 Subject: [PATCH 03/37] Fixed some bugs in the function that calculated the selectivity of the table conditions. --- sql/opt_range.cc | 115 ++++++++++++++++++++++++---------------------- sql/sql_select.cc | 7 ++- 2 files changed, 65 insertions(+), 57 deletions(-) diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 364b01aebb2..d143101a92f 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3324,60 +3324,64 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) table->cond_selectivity= 1.0; - if (bitmap_is_clear_all(used_fields)) - DBUG_RETURN(FALSE); - - PARAM param; - MEM_ROOT alloc; - init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, - MYF(MY_THREAD_SPECIFIC)); - param.thd= thd; - param.mem_root= &alloc; - param.old_root= thd->mem_root; - param.table= table; - param.is_ror_scan= FALSE; - - if (create_key_parts_for_pseudo_indexes(¶m, used_fields)) + if (!bitmap_is_clear_all(used_fields)) { - free_root(&alloc, MYF(0)); - DBUG_RETURN(FALSE); - } + PARAM param; + MEM_ROOT alloc; + init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, + MYF(MY_THREAD_SPECIFIC)); + param.thd= thd; + param.mem_root= &alloc; + param.old_root= thd->mem_root; + param.table= table; + param.is_ror_scan= FALSE; - param.prev_tables= param.read_tables= 0; - param.current_table= table->map; - param.using_real_indexes= FALSE; - param.real_keynr[0]= 0; - param.alloced_sel_args= 0; - - thd->no_errors=1; // Don't warn about NULL - - SEL_TREE *tree; - SEL_ARG **key, **end; - uint idx= 0; - - tree= get_mm_tree(¶m, cond); - - if (!tree) - goto end; - - - for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) - { - double rows; - if (*key) + if (create_key_parts_for_pseudo_indexes(¶m, used_fields)) { - rows= records_in_column_ranges(¶m, idx, *key); - if (rows != HA_POS_ERROR) - (*key)->field->cond_selectivity= rows/table_records; + free_root(&alloc, MYF(0)); + DBUG_RETURN(FALSE); } - } - 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) && - table_field->cond_selectivity < 1.0) - table->cond_selectivity*= table_field->cond_selectivity; + param.prev_tables= param.read_tables= 0; + param.current_table= table->map; + param.using_real_indexes= FALSE; + param.real_keynr[0]= 0; + param.alloced_sel_args= 0; + + thd->no_errors=1; // Don't warn about NULL + + SEL_TREE *tree; + SEL_ARG **key, **end; + uint idx= 0; + + tree= get_mm_tree(¶m, cond); + + if (!tree) + goto free_alloc; + + for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) + { + double rows; + if (*key) + { + rows= records_in_column_ranges(¶m, idx, *key); + if (rows != HA_POS_ERROR) + (*key)->field->cond_selectivity= rows/table_records; + } + } + + 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) && + table_field->cond_selectivity < 1.0) + table->cond_selectivity*= table_field->cond_selectivity; + } + + free_alloc: + thd->mem_root= param.old_root; + free_root(&alloc, MYF(0)); + } /* Calculate the selectivity of the range conditions supported by indexes */ @@ -3412,17 +3416,18 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) } if (i) { - double f1= key_info->actual_rec_per_key(i-1); - double f2= key_info->actual_rec_per_key(i); - table->cond_selectivity*= quick_cond_selectivity * f1 / f2; + table->cond_selectivity*= quick_cond_selectivity; + if (i != used_key_parts) + { + double f1= key_info->actual_rec_per_key(i-1); + double f2= key_info->actual_rec_per_key(i); + table->cond_selectivity*= f1 / f2; + } } } } } -end: - thd->mem_root= param.old_root; - free_root(&alloc, MYF(0)); DBUG_RETURN(FALSE); } diff --git a/sql/sql_select.cc b/sql/sql_select.cc index b6e21a3b8a9..24d518d787a 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6988,8 +6988,11 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, /* Discount the selectivity of the access method used to join table s */ if (s->quick && s->quick->index != MAX_KEY) { - /* A range scan by index s->quick->index is used to access table s */ - sel*= table->quick_rows[s->quick->index]/table_records; + if (!ref) + { + /* A range scan by index s->quick->index is used to access table s */ + sel*= table_records/table->quick_rows[s->quick->index]; + } } else if (ref) { From 4eb245f030da9ce1b4854e9129b08bc68aaef59f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 20 Mar 2013 01:35:05 -0700 Subject: [PATCH 04/37] Correction for the previous fix. --- sql/sql_select.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 24d518d787a..20010eb6465 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6988,7 +6988,7 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, /* Discount the selectivity of the access method used to join table s */ if (s->quick && s->quick->index != MAX_KEY) { - if (!ref) + if (join->positions[idx].key == 0) { /* A range scan by index s->quick->index is used to access table s */ sel*= table_records/table->quick_rows[s->quick->index]; From 1009832c13380365c03f77fcabd0fda470b73390 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 25 Mar 2013 23:48:29 -0700 Subject: [PATCH 05/37] Added histogams for table columns. --- mysql-test/r/mysqld--help.result | 18 +- mysql-test/r/selectivity.result | 111 ++++- mysql-test/r/selectivity_innodb.result | 113 ++++- mysql-test/r/statistics.result | 468 +++++++++--------- mysql-test/r/system_mysql_db.result | 2 + .../suite/funcs_1/r/is_columns_mysql.result | 5 + .../sys_vars/r/histogram_size_basic.result | 136 +++++ ...zer_use_condition_selectivity_basic.result | 8 + .../sys_vars/t/histogram_size_basic.test | 142 ++++++ ...mizer_use_condition_selectivity_basic.test | 4 + mysql-test/t/selectivity.test | 22 + mysql-test/t/statistics.test | 17 + scripts/mysql_system_tables.sql | 2 +- sql/field.cc | 13 + sql/field.h | 9 + sql/opt_range.cc | 113 +++-- sql/sql_class.h | 1 + sql/sql_select.cc | 6 +- sql/sql_statistics.cc | 326 ++++++++++-- sql/sql_statistics.h | 124 ++++- sql/sys_vars.cc | 20 +- sql/table.cc | 2 + sql/table.h | 5 +- 23 files changed, 1328 insertions(+), 339 deletions(-) create mode 100644 mysql-test/suite/sys_vars/r/histogram_size_basic.result create mode 100644 mysql-test/suite/sys_vars/t/histogram_size_basic.test diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index afa3a2ac3af..1804bd1c6fb 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -202,6 +202,8 @@ The following options may be given as the first argument: The maximum length of the result of function GROUP_CONCAT() -?, --help Display this help and exit. + --histogram-size=# Number of bytes used for a histogram. If set to 0, no + histograms are created by ANALYZE. --ignore-builtin-innodb Disable initialization of builtin InnoDB plugin --ignore-db-dirs=name @@ -505,13 +507,16 @@ The following options may be given as the first argument: takes into account to calculate cardinality of a partial join when it searches for the best execution plan Meaning: 1 - use selectivity of index backed range - conditions to calculate cardinality of the partial join + conditions to calculate the cardinality of a partial join if the last joined table is accessed by full table scan - or an index scan 2 - use selectivity of index backed - range conditions to calculate cardinality of the partial - join in any case 3 - additionally always use selectivity - of range conditions that are not backed by any index to - calculate cardinality of the partial join + or an index scan, 2 - use selectivity of index backed + range conditions to calculate the cardinality of a + partial join in any case, 3 - additionally always use + selectivity of range conditions that are not backed by + any index to calculate the cardinality of a partial join, + 4 - use histograms to calculate selectivity of range + conditions that are not backed by any index to calculate + the cardinality of a partial join. --performance-schema Enable the performance schema. --performance-schema-events-waits-history-long-size=# @@ -926,6 +931,7 @@ gdb FALSE general-log FALSE group-concat-max-len 1024 help TRUE +histogram-size 0 ignore-builtin-innodb FALSE ignore-db-dirs init-connect diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 3db8da46ea2..af3f6fdda2d 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -10,6 +10,7 @@ DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_histogram_size=@@histogram_size; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -84,7 +85,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where -4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 @@ -109,6 +110,114 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY +set histogram_size=15; +flush table part; +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.part analyze status Table is already up to date +set optimizer_use_condition_selectivity=4; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set histogram_size=24; +flush table nation; +ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.nation analyze status Table is already up to date +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY DROP DATABASE dbt3_s001; +set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 0a6abfd66d3..9ececad3492 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -13,6 +13,7 @@ DROP DATABASE IF EXISTS dbt3_s001; CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_histogram_size=@@histogram_size; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -87,7 +88,116 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 4.17 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where -4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set histogram_size=15; +flush table part; +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.part analyze status OK +set optimizer_use_condition_selectivity=4; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set histogram_size=24; +flush table nation; +ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.nation analyze status OK +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 @@ -113,6 +223,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY DROP DATABASE dbt3_s001; +set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index ba0390f98db..2abff4416c9 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -64,13 +64,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -87,8 +87,8 @@ COUNT(*) 40 SELECT * FROM mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL 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)", @@ -99,8 +99,8 @@ MIN(t1.a) MAX(t1.a) NULLS_RATIO(t1.a) AVG_FREQUENCY(t1.a) 0 49 0.2000 1.0000 SELECT * FROM mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL 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)", @@ -111,8 +111,8 @@ MIN(t1.b) MAX(t1.b) NULLS_RATIO(t1.b) AVG_FREQUENCY(t1.b) vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 SELECT * FROM mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL 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)", @@ -123,8 +123,8 @@ MIN(t1.c) MAX(t1.c) NULLS_RATIO(t1.c) AVG_FREQUENCY(t1.c) aaaa dddddddd 0.1250 7.0000 SELECT * FROM mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL 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)", @@ -135,8 +135,8 @@ 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 mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL 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)", @@ -206,6 +206,28 @@ 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.column_stats; +set histogram_size=4; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT db_name, table_name, column_name, +min_value, max_value, +nulls_ratio, avg_frequency, +hist_size, HEX(histogram) +FROM mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size HEX(histogram) +test t1 a 0 49 0.0000 1.0000 4 2E62A1D0 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 4 003FBFFF +test t1 c aaaa dddddddd 0.1250 7.0000 4 0055AAFF +test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 4 009393FF +test t1 e 0.01 0.112 0.2250 6.2000 4 000564E1 +test t1 f 1 5 0.2000 6.4000 4 3F7FBFBF +DELETE FROM mysql.column_stats; +set histogram_size= 0; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date CREATE TABLE t3 ( a int NOT NULL PRIMARY KEY, b varchar(32), @@ -238,16 +260,16 @@ db_name table_name cardinality test t1 40 test t3 17 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -267,16 +289,16 @@ db_name table_name cardinality test s1 40 test t3 17 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test s1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test s1 PRIMARY 1 1.0000 @@ -296,16 +318,16 @@ db_name table_name cardinality test t1 40 test t3 17 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -324,13 +346,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -365,13 +387,13 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`y`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 y 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL ALTER TABLE t1 CHANGE COLUMN x b varchar(32), CHANGE COLUMN y e double; SHOW CREATE TABLE t1; @@ -390,13 +412,13 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL ALTER TABLE t1 RENAME TO s1, CHANGE COLUMN b x varchar(32); SHOW CREATE TABLE s1; Table Create Table @@ -417,13 +439,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test s1 40 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test s1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test s1 PRIMARY 1 1.0000 @@ -455,13 +477,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -490,12 +512,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -519,12 +541,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -535,13 +557,13 @@ 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_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -576,12 +598,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -605,12 +627,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -624,13 +646,13 @@ LOAD DATA INFILE 'MYSQLTEST_VARDIR/tmp/save_index_stats' INTO TABLE mysql.index_stats FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -658,12 +680,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -721,12 +743,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -735,13 +757,13 @@ 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_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b NULL NULL 1.0000 NULL NULL 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -758,13 +780,13 @@ 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_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -790,12 +812,12 @@ t1 CREATE TABLE `t1` ( KEY `idx3` (`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -820,12 +842,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -834,13 +856,13 @@ 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_stats; -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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -862,7 +884,7 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); @@ -872,10 +894,10 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 idx2 1 7.0000 @@ -912,13 +934,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -942,19 +964,19 @@ db_name table_name cardinality test t1 40 test t2 40 SELECT * FROM mysql.column_stats 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 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats ORDER BY index_name, prefix_arity, table_name; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -986,13 +1008,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t2 40 SELECT * FROM mysql.column_stats ORDER BY column_name; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -test t2 a 0 49 0.0000 4.0000 1.0000 -test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 -test t2 f 1 5 0.2000 1.0000 6.4000 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats ORDER BY index_name, prefix_arity, table_name; db_name table_name index_name prefix_arity avg_frequency test t2 PRIMARY 1 1.0000 @@ -1122,12 +1144,12 @@ MODIFY COLUMN b text, ADD INDEX idx1 (b(4), e), ADD INDEX idx4 (e, b(4), d); SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -test t2 a 0 49 0.0000 4.0000 1.0000 -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 -test t2 f 1 5 0.2000 1.0000 6.4000 +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t2 idx3 1 8.5000 @@ -1143,18 +1165,18 @@ ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency -test t2 a 0 49 0.0000 4.0000 1.0000 -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 -test t2 f 1 5 0.2000 1.0000 6.4000 -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 -test t1 b NULL NULL 0.2000 17.1250 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t2 idx3 1 8.5000 @@ -1187,7 +1209,7 @@ mysql.column_stats analyze status OK SELECT * FROM mysql.table_stats; db_name table_name cardinality SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency set use_stat_tables='never'; @@ -1198,13 +1220,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -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 -test t1 b NULL NULL 0.2000 17.1250 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 diff --git a/mysql-test/r/system_mysql_db.result b/mysql-test/r/system_mysql_db.result index 4bd5c45d944..4ceedffa5cb 100644 --- a/mysql-test/r/system_mysql_db.result +++ b/mysql-test/r/system_mysql_db.result @@ -286,6 +286,8 @@ column_stats CREATE TABLE `column_stats` ( `nulls_ratio` decimal(12,4) DEFAULT NULL, `avg_length` decimal(12,4) DEFAULT NULL, `avg_frequency` decimal(12,4) DEFAULT NULL, + `hist_size` tinyint(3) unsigned DEFAULT NULL, + `histogram` varbinary(255) 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_stats; 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 df3ca6b366d..bcd9c14f307 100644 --- a/mysql-test/suite/funcs_1/r/is_columns_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_columns_mysql.result @@ -13,6 +13,8 @@ def mysql column_stats avg_frequency 8 NULL YES decimal NULL NULL 12 4 NULL NULL def mysql column_stats avg_length 7 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references def mysql column_stats column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql column_stats db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references +def mysql column_stats histogram 10 NULL YES varbinary 255 255 NULL NULL NULL NULL NULL varbinary(255) select,insert,update,references +def mysql column_stats hist_size 9 NULL YES tinyint NULL NULL 3 0 NULL NULL NULL tinyint(3) unsigned select,insert,update,references def mysql column_stats max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references def mysql column_stats min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references def mysql column_stats nulls_ratio 6 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references @@ -256,6 +258,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME 1.0000 blob NULL NULL 1.0000 longblob NULL NULL +1.0000 varbinary NULL NULL 1.0000 char latin1 latin1_bin 1.0000 char latin1 latin1_swedish_ci 1.0000 varchar latin1 latin1_swedish_ci @@ -328,6 +331,8 @@ NULL mysql columns_priv Timestamp timestamp NULL NULL NULL NULL timestamp NULL mysql column_stats nulls_ratio decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_length decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_frequency decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stats hist_size tinyint NULL NULL NULL NULL tinyint(3) unsigned +1.0000 mysql column_stats histogram varbinary 255 255 NULL NULL varbinary(255) 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) diff --git a/mysql-test/suite/sys_vars/r/histogram_size_basic.result b/mysql-test/suite/sys_vars/r/histogram_size_basic.result new file mode 100644 index 00000000000..1f310600d00 --- /dev/null +++ b/mysql-test/suite/sys_vars/r/histogram_size_basic.result @@ -0,0 +1,136 @@ +SET @start_global_value = @@global.histogram_size; +SELECT @start_global_value; +@start_global_value +0 +SET @start_session_value = @@session.histogram_size; +SELECT @start_session_value; +@start_session_value +0 +'#--------------------FN_DYNVARS_053_01-------------------------#' +SET @@global.histogram_size = DEFAULT; +SELECT @@global.histogram_size; +@@global.histogram_size +0 +SET @@session.histogram_size = DEFAULT; +SELECT @@session.histogram_size; +@@session.histogram_size +0 +'#--------------------FN_DYNVARS_053_03-------------------------#' +SET @@global.histogram_size = 1; +SELECT @@global.histogram_size; +@@global.histogram_size +1 +SET @@global.histogram_size = 31; +SELECT @@global.histogram_size; +@@global.histogram_size +31 +SET @@global.histogram_size = 255; +SELECT @@global.histogram_size; +@@global.histogram_size +255 +'#--------------------FN_DYNVARS_053_04-------------------------#' +SET @@session.histogram_size = 1; +SELECT @@session.histogram_size; +@@session.histogram_size +1 +SET @@session.histogram_size = 31; +SELECT @@session.histogram_size; +@@session.histogram_size +31 +SET @@session.histogram_size = 255; +SELECT @@session.histogram_size; +@@session.histogram_size +255 +'#------------------FN_DYNVARS_053_05-----------------------#' +SET @@global.histogram_size = -1; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '-1' +SELECT @@global.histogram_size; +@@global.histogram_size +0 +SET @@global.histogram_size = 256; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '256' +SELECT @@global.histogram_size; +@@global.histogram_size +255 +SET @@global.histogram_size = 1024; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '1024' +SELECT @@global.histogram_size; +@@global.histogram_size +255 +SET @@global.histogram_size = 4.5; +ERROR 42000: Incorrect argument type to variable 'histogram_size' +SELECT @@global.histogram_size; +@@global.histogram_size +255 +SET @@global.histogram_size = test; +ERROR 42000: Incorrect argument type to variable 'histogram_size' +SELECT @@global.histogram_size; +@@global.histogram_size +255 +SET @@session.histogram_size = -1; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '-1' +SELECT @@session.histogram_size; +@@session.histogram_size +0 +SET @@session.histogram_size = 256; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '256' +SELECT @@session.histogram_size; +@@session.histogram_size +255 +SET @@session.histogram_size = 1024; +Warnings: +Warning 1292 Truncated incorrect histogram_size value: '1024' +SELECT @@session.histogram_size; +@@session.histogram_size +255 +SET @@session.histogram_size = 4.5; +ERROR 42000: Incorrect argument type to variable 'histogram_size' +SELECT @@session.histogram_size; +@@session.histogram_size +255 +SET @@session.histogram_size = test; +ERROR 42000: Incorrect argument type to variable 'histogram_size' +SELECT @@session.histogram_size; +@@session.histogram_size +255 +'#------------------FN_DYNVARS_053_06-----------------------#' +SELECT @@global.histogram_size = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='histogram_size'; +@@global.histogram_size = VARIABLE_VALUE +1 +'#------------------FN_DYNVARS_053_07-----------------------#' +SELECT @@session.histogram_size = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='histogram_size'; +@@session.histogram_size = VARIABLE_VALUE +1 +'#------------------FN_DYNVARS_053_08-----------------------#' +SET @@global.histogram_size = TRUE; +SET @@global.histogram_size = FALSE; +'#---------------------FN_DYNVARS_001_09----------------------#' +SET @@global.histogram_size = 10; +SELECT @@histogram_size = @@global.histogram_size; +@@histogram_size = @@global.histogram_size +0 +'#---------------------FN_DYNVARS_001_10----------------------#' +SET @@histogram_size = 100; +SELECT @@histogram_size = @@local.histogram_size; +@@histogram_size = @@local.histogram_size +1 +SELECT @@local.histogram_size = @@session.histogram_size; +@@local.histogram_size = @@session.histogram_size +1 +SET @@global.histogram_size = @start_global_value; +SELECT @@global.histogram_size; +@@global.histogram_size +0 +SET @@session.histogram_size = @start_session_value; +SELECT @@session.histogram_size; +@@session.histogram_size +0 diff --git a/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result b/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result index 332194e369e..418c221b5aa 100644 --- a/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result +++ b/mysql-test/suite/sys_vars/r/optimizer_use_condition_selectivity_basic.result @@ -40,6 +40,10 @@ SET @@global.optimizer_use_condition_selectivity = 3; SELECT @@global.optimizer_use_condition_selectivity; @@global.optimizer_use_condition_selectivity 3 +SET @@global.optimizer_use_condition_selectivity = 4; +SELECT @@global.optimizer_use_condition_selectivity; +@@global.optimizer_use_condition_selectivity +4 '#--------------------FN_DYNVARS_115_04-------------------------#' SELECT @@session.optimizer_use_condition_selectivity; @@session.optimizer_use_condition_selectivity @@ -56,6 +60,10 @@ SET @@session.optimizer_use_condition_selectivity = 3; SELECT @@session.optimizer_use_condition_selectivity; @@session.optimizer_use_condition_selectivity 3 +SET @@session.optimizer_use_condition_selectivity = 4; +SELECT @@session.optimizer_use_condition_selectivity; +@@session.optimizer_use_condition_selectivity +4 '#------------------FN_DYNVARS_115_05-----------------------#' SET @@global.optimizer_use_condition_selectivity = ON; ERROR 42000: Incorrect argument type to variable 'optimizer_use_condition_selectivity' diff --git a/mysql-test/suite/sys_vars/t/histogram_size_basic.test b/mysql-test/suite/sys_vars/t/histogram_size_basic.test new file mode 100644 index 00000000000..d65936e3616 --- /dev/null +++ b/mysql-test/suite/sys_vars/t/histogram_size_basic.test @@ -0,0 +1,142 @@ +--source include/load_sysvars.inc + +############################################################## +# START OF histogram_size TESTS # +############################################################## + + +############################################################# +# Save initial value # +############################################################# + +SET @start_global_value = @@global.histogram_size; +SELECT @start_global_value; +SET @start_session_value = @@session.histogram_size; +SELECT @start_session_value; + +--echo '#--------------------FN_DYNVARS_053_01-------------------------#' +################################################################ +# Display the DEFAULT value of histogram_size # +################################################################ + +SET @@global.histogram_size = DEFAULT; +SELECT @@global.histogram_size; + +SET @@session.histogram_size = DEFAULT; +SELECT @@session.histogram_size; + +--echo '#--------------------FN_DYNVARS_053_03-------------------------#' +######################################################################## +# Change the value of histogram_size to a valid value for GLOBAL Scope # +######################################################################## + +SET @@global.histogram_size = 1; +SELECT @@global.histogram_size; +SET @@global.histogram_size = 31; +SELECT @@global.histogram_size; +SET @@global.histogram_size = 255; +SELECT @@global.histogram_size; + +--echo '#--------------------FN_DYNVARS_053_04-------------------------#' +######################################################################### +# Change the value of histogram_size to a valid value for SESSION Scope # +######################################################################### + +SET @@session.histogram_size = 1; +SELECT @@session.histogram_size; +SET @@session.histogram_size = 31; +SELECT @@session.histogram_size; +SET @@session.histogram_size = 255; +SELECT @@session.histogram_size; + +--echo '#------------------FN_DYNVARS_053_05-----------------------#' +########################################################## +# Change the value of histogram_size to an invalid value # +########################################################### + +SET @@global.histogram_size = -1; +SELECT @@global.histogram_size; +SET @@global.histogram_size = 256; +SELECT @@global.histogram_size; +SET @@global.histogram_size = 1024; +SELECT @@global.histogram_size; + +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.histogram_size = 4.5; +SELECT @@global.histogram_size; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.histogram_size = test; +SELECT @@global.histogram_size; + +SET @@session.histogram_size = -1; +SELECT @@session.histogram_size; +SET @@session.histogram_size = 256; +SELECT @@session.histogram_size; +SET @@session.histogram_size = 1024; +SELECT @@session.histogram_size; + +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.histogram_size = 4.5; +SELECT @@session.histogram_size; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.histogram_size = test; +SELECT @@session.histogram_size; + +--echo '#------------------FN_DYNVARS_053_06-----------------------#' +#################################################################### +# Check if the value in GLOBAL Table matches value in variable # +#################################################################### + +SELECT @@global.histogram_size = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='histogram_size'; + +--echo '#------------------FN_DYNVARS_053_07-----------------------#' +#################################################################### +# Check if the value in SESSION Table matches value in variable # +#################################################################### + +SELECT @@session.histogram_size = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='histogram_size'; + + +--echo '#------------------FN_DYNVARS_053_08-----------------------#' +#################################################################### +# Check if TRUE and FALSE values can be used on variable # +#################################################################### + +SET @@global.histogram_size = TRUE; +SET @@global.histogram_size = FALSE; + +--echo '#---------------------FN_DYNVARS_001_09----------------------#' +################################################################################# +# Check if accessing variable with and without GLOBAL point to same variable # +################################################################################# + +SET @@global.histogram_size = 10; +SELECT @@histogram_size = @@global.histogram_size; + +--echo '#---------------------FN_DYNVARS_001_10----------------------#' +######################################################################################################## +# Check if accessing variable with SESSION,LOCAL and without SCOPE points to same session variable # +######################################################################################################## + +SET @@histogram_size = 100; +SELECT @@histogram_size = @@local.histogram_size; +SELECT @@local.histogram_size = @@session.histogram_size; + +#################################### +# Restore initial value # +#################################### + +SET @@global.histogram_size = @start_global_value; +SELECT @@global.histogram_size; +SET @@session.histogram_size = @start_session_value; +SELECT @@session.histogram_size; + + +################################################### +# END OF histogram_size TESTS # +################################################### + diff --git a/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test b/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test index d898cf448dc..58a1af4b975 100644 --- a/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test +++ b/mysql-test/suite/sys_vars/t/optimizer_use_condition_selectivity_basic.test @@ -52,6 +52,8 @@ SET @@global.optimizer_use_condition_selectivity = 2; SELECT @@global.optimizer_use_condition_selectivity; SET @@global.optimizer_use_condition_selectivity = 3; SELECT @@global.optimizer_use_condition_selectivity; +SET @@global.optimizer_use_condition_selectivity = 4; +SELECT @@global.optimizer_use_condition_selectivity; --echo '#--------------------FN_DYNVARS_115_04-------------------------#' @@ -66,6 +68,8 @@ SET @@session.optimizer_use_condition_selectivity = 2; SELECT @@session.optimizer_use_condition_selectivity; SET @@session.optimizer_use_condition_selectivity = 3; SELECT @@session.optimizer_use_condition_selectivity; +SET @@session.optimizer_use_condition_selectivity = 4; +SELECT @@session.optimizer_use_condition_selectivity; --echo '#------------------FN_DYNVARS_115_05-----------------------#' diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 4756c6d4816..77089271cdd 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -16,6 +16,7 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_histogram_size=@@histogram_size; --disable_query_log --disable_result_log @@ -58,8 +59,29 @@ set optimizer_use_condition_selectivity=3; eval EXPLAIN EXTENDED $Q20; eval $Q20; +set histogram_size=15; + +flush table part; + +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); + +set optimizer_use_condition_selectivity=4; + +eval EXPLAIN EXTENDED $Q20; +eval $Q20; + +set histogram_size=24; + +flush table nation; + +ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); + +eval EXPLAIN EXTENDED $Q20; +eval $Q20; + DROP DATABASE dbt3_s001; +set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 4f2d0510c11..65412d849ed 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -165,6 +165,23 @@ 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.column_stats; + +set histogram_size=4; +ANALYZE TABLE t1; + +SELECT db_name, table_name, column_name, + min_value, max_value, + nulls_ratio, avg_frequency, + hist_size, HEX(histogram) + FROM mysql.column_stats; + +DELETE FROM mysql.column_stats; +set histogram_size= 0; +ANALYZE TABLE t1; + + CREATE TABLE t3 ( a int NOT NULL PRIMARY KEY, b varchar(32), diff --git a/scripts/mysql_system_tables.sql b/scripts/mysql_system_tables.sql index a55c5f60351..6a54f339cd0 100644 --- a/scripts/mysql_system_tables.sql +++ b/scripts/mysql_system_tables.sql @@ -108,6 +108,6 @@ set @had_proxies_priv_table= @@warning_count != 0; CREATE TABLE IF NOT EXISTS table_stats (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_stats (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 column_stats (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, hist_size tinyint unsigned, histogram varbinary(255), 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_stats (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.cc b/sql/field.cc index e54a3e59795..afa12f84178 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -8420,6 +8420,19 @@ my_decimal *Field_bit::val_decimal(my_decimal *deciaml_value) } +double Field_bit::middle_point_pos(Field *min, Field *max) +{ + double n, d; + n= val_real() - min->val_real(); + if (n < 0) + return 0.0; + d= max->val_real() - min->val_real(); + if (d <= 0) + return 1.0; + return min(n/d, 1.0); +} + + /* Compare two bit fields using pointers within the record. SYNOPSIS diff --git a/sql/field.h b/sql/field.h index 40cbcca09ad..b98a1fdba14 100644 --- a/sql/field.h +++ b/sql/field.h @@ -472,6 +472,10 @@ public: } return update_fl; } + virtual void store_field_value(uchar *val, uint len) + { + memcpy(ptr, val, len); + } virtual uint decimals() const { return 0; } /* Caller beware: sql_type can change str.Ptr, so check @@ -2299,6 +2303,11 @@ public: } return update_fl; } + void store_field_value(uchar *val, uint len) + { + store(*((longlong *)val), TRUE); + } + double middle_point_pos(Field *min, Field *max); 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/opt_range.cc b/sql/opt_range.cc index 364b01aebb2..904356f6eb7 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3324,60 +3324,64 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) table->cond_selectivity= 1.0; - if (bitmap_is_clear_all(used_fields)) - DBUG_RETURN(FALSE); - - PARAM param; - MEM_ROOT alloc; - init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, - MYF(MY_THREAD_SPECIFIC)); - param.thd= thd; - param.mem_root= &alloc; - param.old_root= thd->mem_root; - param.table= table; - param.is_ror_scan= FALSE; - - if (create_key_parts_for_pseudo_indexes(¶m, used_fields)) + if (!bitmap_is_clear_all(used_fields)) { - free_root(&alloc, MYF(0)); - DBUG_RETURN(FALSE); - } - - param.prev_tables= param.read_tables= 0; - param.current_table= table->map; - param.using_real_indexes= FALSE; - param.real_keynr[0]= 0; - param.alloced_sel_args= 0; - - thd->no_errors=1; // Don't warn about NULL - - SEL_TREE *tree; - SEL_ARG **key, **end; - uint idx= 0; + PARAM param; + MEM_ROOT alloc; + SEL_TREE *tree; + SEL_ARG **key, **end; + uint idx= 0; - tree= get_mm_tree(¶m, cond); + init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, + MYF(MY_THREAD_SPECIFIC)); + param.thd= thd; + param.mem_root= &alloc; + param.old_root= thd->mem_root; + param.table= table; + param.is_ror_scan= FALSE; - if (!tree) - goto end; - - - for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) - { - double rows; - if (*key) + if (create_key_parts_for_pseudo_indexes(¶m, used_fields)) { - rows= records_in_column_ranges(¶m, idx, *key); - if (rows != HA_POS_ERROR) - (*key)->field->cond_selectivity= rows/table_records; + free_root(&alloc, MYF(0)); + goto free_alloc; } - } - 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) && - table_field->cond_selectivity < 1.0) - table->cond_selectivity*= table_field->cond_selectivity; + param.prev_tables= param.read_tables= 0; + param.current_table= table->map; + param.using_real_indexes= FALSE; + param.real_keynr[0]= 0; + param.alloced_sel_args= 0; + + thd->no_errors=1; + + tree= get_mm_tree(¶m, cond); + + if (!tree) + goto free_alloc; + + for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) + { + double rows; + if (*key) + { + rows= records_in_column_ranges(¶m, idx, *key); + if (rows != HA_POS_ERROR) + (*key)->field->cond_selectivity= rows/table_records; + } + } + + 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) && + table_field->cond_selectivity < 1.0) + table->cond_selectivity*= table_field->cond_selectivity; + } + + free_alloc: + thd->mem_root= param.old_root; + free_root(&alloc, MYF(0)); + } /* Calculate the selectivity of the range conditions supported by indexes */ @@ -3412,17 +3416,18 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) } if (i) { - double f1= key_info->actual_rec_per_key(i-1); - double f2= key_info->actual_rec_per_key(i); - table->cond_selectivity*= quick_cond_selectivity * f1 / f2; + table->cond_selectivity*= quick_cond_selectivity; + if (i != used_key_parts) + { + double f1= key_info->actual_rec_per_key(i-1); + double f2= key_info->actual_rec_per_key(i); + table->cond_selectivity*= f1 / f2; + } } } } } -end: - thd->mem_root= param.old_root; - free_root(&alloc, MYF(0)); DBUG_RETURN(FALSE); } diff --git a/sql/sql_class.h b/sql/sql_class.h index e2fe3a53dcc..2844cab9b4e 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -501,6 +501,7 @@ typedef struct system_variables ulong optimizer_search_depth; ulong optimizer_use_condition_selectivity; ulong use_stat_tables; + ulong histogram_size; ulong preload_buff_size; ulong profiling_history_size; ulong read_buff_size; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index bc9e05fe2d9..a6d995434af 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6988,8 +6988,10 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, /* Discount the selectivity of the access method used to join table s */ if (s->quick && s->quick->index != MAX_KEY) { - /* A range scan by index s->quick->index is used to access table s */ - sel*= table_records/table->quick_rows[s->quick->index]; + if (join->positions[idx].key == 0) + { + sel*= table->quick_rows[s->quick->index]/table_records; + } } else if (ref) { diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 5338632067a..8c0b2730b02 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -889,7 +889,7 @@ public: 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++) + for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_HISTOGRAM; i++) { Field *stat_field= stat_table->field[i]; if (table_field->collected_stats->is_null(i)) @@ -924,7 +924,17 @@ public: break; case COLUMN_STAT_AVG_FREQUENCY: stat_field->store(table_field->collected_stats->get_avg_frequency()); - break; + break; + case COLUMN_STAT_HIST_SIZE: + stat_field->store(table_field->collected_stats->histogram.get_size()); + break; + case COLUMN_STAT_HISTOGRAM: + const char * col_histogram= + (const char *) (table_field->collected_stats->histogram.get_values()); + stat_field->store(col_histogram, + table_field->collected_stats->histogram.get_size(), + &my_charset_bin); + break; } } } @@ -961,7 +971,7 @@ public: 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++) + for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_HIST_SIZE; i++) { Field *stat_field= stat_table->field[i]; @@ -993,6 +1003,9 @@ public: break; case COLUMN_STAT_AVG_FREQUENCY: table_field->read_stats->set_avg_frequency(stat_field->val_real()); + break; + case COLUMN_STAT_HIST_SIZE: + table_field->read_stats->histogram.set_size(stat_field->val_int()); break; } } @@ -1000,6 +1013,21 @@ public: } } + void get_histogram_value() + { + if (find_stat()) + { + char buff[MAX_FIELD_WIDTH]; + String val(buff, sizeof(buff), &my_charset_utf8_bin); + uint fldno= COLUMN_STAT_HISTOGRAM; + Field *stat_field= stat_table->field[fldno]; + table_field->read_stats->set_not_null(fldno); + stat_field->val_str(&val); + memcpy(table_field->read_stats->histogram.get_values(), + val.ptr(), table_field->read_stats->histogram.get_size()); + } + } + }; @@ -1202,6 +1230,72 @@ public: }; +class Histogram_builder +{ + Field *column; + uint col_length; + ha_rows records; + Field *min_value; + Field *max_value; + Histogram *histogram; + uint hist_size; + double bucket_capacity; + uint curr_bucket; + ulonglong count; + ulonglong count_distinct; + +public: + Histogram_builder(Field *col, uint col_len, ha_rows rows) + : column(col), col_length(col_len), records(rows) + { + Column_statistics *col_stats= col->collected_stats; + min_value= col_stats->min_value; + max_value= col_stats->max_value; + histogram= &col_stats->histogram; + hist_size= histogram->get_size(); + bucket_capacity= (double) records / (hist_size + 1); + curr_bucket= 0; + count= 0; + count_distinct= 0; + } + + ulonglong get_count_distinct() { return count_distinct; } + + int next(void *elem, element_count elem_cnt) + { + count_distinct++; + count+= elem_cnt; + if (curr_bucket == hist_size) + return 0; + if (count > bucket_capacity * (curr_bucket + 1)) + { + column->store_field_value((uchar *) elem, col_length); + histogram->set_value(curr_bucket, + column->middle_point_pos(min_value, max_value)); + curr_bucket++; + while (curr_bucket != hist_size && + count > bucket_capacity * (curr_bucket + 1)) + { + histogram->set_prev_value(curr_bucket); + curr_bucket++; + } + } + return 0; + } +}; + + +C_MODE_START + +int histogram_build_walk(void *elem, element_count elem_cnt, void *arg) +{ + Histogram_builder *hist_builder= (Histogram_builder *) arg; + return hist_builder->next(elem, elem_cnt); +} + +C_MODE_END + + /* The class Count_distinct_field is a helper class used to calculate the number of distinct values for a column. The class employs the @@ -1221,6 +1315,8 @@ protected: uint tree_key_length; /* The length of the keys for the elements of 'tree */ public: + + Count_distinct_field() {} /** @param @@ -1239,27 +1335,10 @@ public: 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= new Unique((qsort_cmp2) simple_str_key_cmp, (void*) field, tree_key_length, max_heap_table_size); } @@ -1300,9 +1379,36 @@ public: tree->walk(table_field->table, count_distinct_walk, (void*) &count); return count; } + + ulonglong get_value_with_histogram(ha_rows rows) + { + Histogram_builder hist_builder(table_field, tree_key_length, rows); + tree->walk(table_field->table, histogram_build_walk, (void *) &hist_builder); + return hist_builder.get_count_distinct(); + } + + uint get_hist_size() + { + return table_field->collected_stats->histogram.get_size(); + } + + uchar *get_histogram() + { + return table_field->collected_stats->histogram.get_values(); + } + }; +static +int simple_ulonglong_key_cmp(void* arg, uchar* key1, uchar* key2) +{ + ulonglong *val1= (ulonglong *) key1; + ulonglong *val2= (ulonglong *) key2; + return *val1 > *val2 ? 1 : *val1 == *val2 ? 0 : -1; +} + + /* 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. @@ -1312,8 +1418,17 @@ public: 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) {} + { + table_field= field; + tree_key_length= sizeof(ulonglong); + + tree= new Unique((qsort_cmp2) simple_ulonglong_key_cmp, + (void*) &tree_key_length, + tree_key_length, max_heap_table_size); + } + bool add() { longlong val= table_field->val_int(); @@ -1672,13 +1787,26 @@ int alloc_statistics_for_table(THD* thd, TABLE *table) ulong *idx_avg_frequency= (ulong*) alloc_root(&table->mem_root, sizeof(ulong) * key_parts); - if (!table_stats || !column_stats || !index_stats || !idx_avg_frequency) + uint columns= 0; + for (field_ptr= table->field; *field_ptr; field_ptr++) + { + if (bitmap_is_set(table->read_set, (*field_ptr)->field_index)) + columns++; + } + uint hist_size= thd->variables.histogram_size; + uchar *histogram= NULL; + if (hist_size > 0) + histogram= (uchar *) alloc_root(&table->mem_root, hist_size * columns); + + if (!table_stats || !column_stats || !index_stats || !idx_avg_frequency || + (hist_size && !histogram)) 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; + table_stats->histograms= histogram; memset(column_stats, 0, sizeof(Column_statistics) * (fields+1)); @@ -1687,6 +1815,12 @@ int alloc_statistics_for_table(THD* thd, TABLE *table) (*field_ptr)->collected_stats= column_stats; (*field_ptr)->collected_stats->max_value= NULL; (*field_ptr)->collected_stats->min_value= NULL; + if (bitmap_is_set(table->read_set, (*field_ptr)->field_index)) + { + column_stats->histogram.set_size(hist_size); + column_stats->histogram.set_values(histogram); + histogram+= hist_size; + } } memset(idx_avg_frequency, 0, sizeof(ulong) * key_parts); @@ -1903,10 +2037,51 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, if (!is_safe) mysql_mutex_unlock(&table_share->LOCK_ha_data); - DBUG_RETURN(0); } +static +int alloc_histograms_for_table_share(THD* thd, TABLE_SHARE *table_share, + bool is_safe) +{ + TABLE_STATISTICS_CB *stats_cb= &table_share->stats_cb; + + DBUG_ENTER("alloc_histograms_for_table_share"); + + if (!is_safe) + mysql_mutex_lock(&table_share->LOCK_ha_data); + + if (stats_cb->histograms_can_be_read) + { + if (!is_safe) + mysql_mutex_unlock(&table_share->LOCK_ha_data); + DBUG_RETURN(0); + } + + Table_statistics *table_stats= stats_cb->table_stats; + ulong total_hist_size= table_stats->total_hist_size; + + if (total_hist_size && !table_stats->histograms) + { + uchar *histograms= (uchar *) alloc_root(&stats_cb->mem_root, + total_hist_size); + if (!histograms) + { + if (!is_safe) + mysql_mutex_unlock(&table_share->LOCK_ha_data); + DBUG_RETURN(1); + } + memset(histograms, 0, total_hist_size); + table_stats->histograms= histograms; + stats_cb->histograms_can_be_read= TRUE; + } + + if (!is_safe) + mysql_mutex_unlock(&table_share->LOCK_ha_data); + + DBUG_RETURN(0); + +} /** @brief @@ -2006,14 +2181,28 @@ void Column_statistics_collected::finish(ha_rows rows) set_not_null(COLUMN_STAT_AVG_LENGTH); } if (count_distinct) - { - ulonglong distincts= count_distinct->get_value(); + { + ulonglong distincts; + uint hist_size= count_distinct->get_hist_size(); + if (hist_size == 0) + distincts= count_distinct->get_value(); + else + distincts= count_distinct->get_value_with_histogram(rows - nulls); if (distincts) { val= (double) (rows - nulls) / distincts; set_avg_frequency(val); set_not_null(COLUMN_STAT_AVG_FREQUENCY); } + else + hist_size= 0; + histogram.set_size(hist_size); + set_not_null(COLUMN_STAT_HIST_SIZE); + if (hist_size && distincts) + { + histogram.set_values(count_distinct->get_histogram()); + set_not_null(COLUMN_STAT_HISTOGRAM); + } delete count_distinct; count_distinct= NULL; } @@ -2234,16 +2423,19 @@ int collect_statistics_for_table(THD *thd, TABLE *table) table->collected_stats->cardinality= rows; } + bitmap_clear_all(table->write_set); 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; + bitmap_set_bit(table->write_set, table_field->field_index); if (!rc) table_field->collected_stats->finish(rows); else table_field->collected_stats->cleanup(); } +bitmap_clear_all(table->write_set); if (!rc) { @@ -2421,6 +2613,7 @@ int read_statistics_for_table(THD *thd, TABLE *table, TABLE_LIST *stat_tables) Field **field_ptr; KEY *key_info, *key_info_end; TABLE_SHARE *table_share= table->s; + Table_statistics *read_stats= table_share->stats_cb.table_stats; DBUG_ENTER("read_statistics_for_table"); @@ -2432,16 +2625,18 @@ int read_statistics_for_table(THD *thd, TABLE *table, TABLE_LIST *stat_tables) /* Read statistics from the statistical table column_stats */ stat_table= stat_tables[COLUMN_STAT].table; + ulong total_hist_size= 0; Column_stat column_stat(stat_table, table); for (field_ptr= table_share->field; *field_ptr; field_ptr++) { table_field= *field_ptr; column_stat.set_key_fields(table_field); column_stat.get_stat_values(); + total_hist_size+= table_field->read_stats->histogram.get_size(); } + read_stats->total_hist_size= total_hist_size; /* Read statistics from the statistical table index_stats */ - Table_statistics *read_stats= table_share->stats_cb.table_stats; stat_table= stat_tables[INDEX_STAT].table; Index_stat index_stat(stat_table, table); for (key_info= table_share->key_info, @@ -2559,10 +2754,14 @@ bool statistics_for_tables_is_needed(THD *thd, TABLE_LIST *tables) TABLE_SHARE *table_share= tl->table->s; if (table_share && table_share->stats_cb.stats_can_be_read && - !table_share->stats_cb.stats_is_read) + (!table_share->stats_cb.stats_is_read || + (!table_share->stats_cb.histograms_are_read && + thd->variables.optimizer_use_condition_selectivity > 3))) return TRUE; if (table_share->stats_cb.stats_is_read) tl->table->stats_is_read= TRUE; + if (table_share->stats_cb.histograms_are_read) + tl->table->histograms_are_read= TRUE; } } @@ -2570,6 +2769,41 @@ bool statistics_for_tables_is_needed(THD *thd, TABLE_LIST *tables) } +static +int read_histograms_for_table(THD *thd, TABLE *table, TABLE_LIST *stat_tables) +{ + TABLE_SHARE *table_share= table->s; + + DBUG_ENTER("read_histograms_for_table"); + + if (!table_share->stats_cb.histograms_can_be_read) + { + (void) alloc_histograms_for_table_share(thd, table_share, FALSE); + } + if (table_share->stats_cb.histograms_can_be_read && + !table_share->stats_cb.histograms_are_read) + { + Field **field_ptr; + uchar *histogram= table_share->stats_cb.table_stats->histograms; + 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++) + { + Field *table_field= *field_ptr; + uint hist_size= table_field->read_stats->histogram.get_size(); + if (hist_size) + { + column_stat.set_key_fields(table_field); + table_field->read_stats->histogram.set_values(histogram); + column_stat.get_histogram_value(); + histogram+= hist_size; + } + } + } + + DBUG_RETURN(0); +} + /** @brief Read statistics for tables from a table list if it is needed @@ -2597,7 +2831,7 @@ 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"); + DBUG_ENTER("read_statistics_for_tables_if_needed"); DEBUG_SYNC(thd, "statistics_read_start"); @@ -2624,6 +2858,14 @@ int read_statistics_for_tables_if_needed(THD *thd, TABLE_LIST *tables) } if (table_share->stats_cb.stats_is_read) tl->table->stats_is_read= TRUE; + if (thd->variables.optimizer_use_condition_selectivity > 3 && + table_share && !table_share->stats_cb.histograms_are_read) + { + (void) read_histograms_for_table(thd, tl->table, stat_tables); + table_share->stats_cb.histograms_are_read= TRUE; + } + if (table_share->stats_cb.stats_is_read) + tl->table->histograms_are_read= TRUE; } } @@ -3083,20 +3325,40 @@ double get_column_range_cardinality(Field *field, res= table->stat_records(); else if (min_endp->length == max_endp->length && !memcmp(min_endp->key, max_endp->key, min_endp->length)) - { - res= col_stats->get_avg_frequency(); + { + double avg_frequency= col_stats->get_avg_frequency(); + res= avg_frequency; + if (avg_frequency > 1.0 + 0.000001 && + col_stats->min_value && col_stats->max_value) + { + Histogram *hist= &col_stats->histogram; + if (hist->get_size() > 0) + { + double pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + res= table->stat_records() * + hist->point_selectivity(pos, + avg_frequency / table->stat_records()); + } + } } else { if (col_stats->min_value && col_stats->max_value) { + double sel; store_key_image_to_rec(field, (uchar *) min_endp->key, min_endp->length); double min_mp_pos= field->middle_point_pos(col_stats->min_value, col_stats->max_value); store_key_image_to_rec(field, (uchar *) max_endp->key, max_endp->length); double max_mp_pos= field->middle_point_pos(col_stats->min_value, col_stats->max_value); - res= table->stat_records() * (max_mp_pos - min_mp_pos); + Histogram *hist= &col_stats->histogram; + if (hist->get_size() == 0) + sel= (max_mp_pos - min_mp_pos); + else + sel= hist->range_selectivity(min_mp_pos, max_mp_pos); + res= table->stat_records() * sel; } else res= table->stat_records(); diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 6bf552b92a0..9a2b5c2433b 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -16,15 +16,6 @@ #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. -*/ - typedef enum enum_use_stat_tables_mode { @@ -40,6 +31,16 @@ enum enum_stat_tables INDEX_STAT, }; + +/* + 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_table_stat_col { TABLE_STAT_DB_NAME, @@ -56,7 +57,9 @@ enum enum_column_stat_col COLUMN_STAT_MAX_VALUE, COLUMN_STAT_NULLS_RATIO, COLUMN_STAT_AVG_LENGTH, - COLUMN_STAT_AVG_FREQUENCY + COLUMN_STAT_AVG_FREQUENCY, + COLUMN_STAT_HIST_SIZE, + COLUMN_STAT_HISTOGRAM }; enum enum_index_stat_col @@ -96,6 +99,98 @@ double get_column_range_cardinality(Field *field, key_range *min_endp, key_range *max_endp); +#define HIST_FACTOR 255 +#define INV_HIST_FACTOR ((double) 1.0 / HIST_FACTOR) + +class Histogram +{ +private: +public: + +private: + uint8 size; + uint8 *values; + + uint find_bucket(double pos, bool first) + { + uint8 val= (uint8) (pos * HIST_FACTOR); + int lp= 0; + int rp= size - 1; + int i= 0; + for (int d= size / 2 ; d; d= (rp - lp) / 2) + { + i= lp + d; + if (val == values[i]) + break; + if (val < values[i]) + rp= i; + else if (val > values[i + 1]) + lp= i + 1; + else + break; + } + if (val == values[i]) + { + if (first) + { + while(i && val == values[i - 1]) + i--; + } + else + { + while(i + 1 < size && val == values[i + 1]) + i++; + } + } + return i; + } + +public: + + uint get_size() { return (uint) size; } + + uchar *get_values() { return (uchar *) values; } + + void set_size (ulonglong sz) { size= (uint8) sz; } + + void set_values (uchar *vals) { values= (uint8 *) vals; } + + void set_value(uint i, double val) + { + values[i]= (uint8) (val * HIST_FACTOR); + } + + void set_prev_value(uint i) { values[i]= values[i-1]; } + + + double range_selectivity(double min_pos, double max_pos) + { + double sel; + double bucket_sel= 1.0/(size + 1); + uint min= find_bucket(min_pos, TRUE); + uint max= find_bucket(max_pos, FALSE); + sel= bucket_sel * (max - min + 1); + return sel; + } + + double point_selectivity(double pos, double avg_sel) + { + double sel; + double bucket_sel= 1.0/(size + 1); + uint min= find_bucket(pos, TRUE); + uint max= min; + while (max + 1 < size && values[max + 1] == values[max]) + max++; + double width= ((max + 1 == size ? 1.0 : values[max]) - + (min == 0 ? 0.0 : values[min-1])) * + INV_HIST_FACTOR; + sel= avg_sel * (bucket_sel * (max + 1 - min)) / width; + return sel; + } + +}; + + class Columns_statistics; class Index_statistics; @@ -111,8 +206,9 @@ public: uchar *min_max_record_buffers; /* Record buffers for min/max values */ 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 */ - + ulong *idx_avg_frequency; /* Array of records per key for index prefixes */ + ulong total_hist_size; + uchar *histograms; /* Sequence of histograms */ }; @@ -167,10 +263,12 @@ private: public: + Histogram histogram; + void set_all_nulls() { column_stat_nulls= - ((1 << (COLUMN_STAT_AVG_FREQUENCY-COLUMN_STAT_COLUMN_NAME))-1) << + ((1 << (COLUMN_STAT_HISTOGRAM-COLUMN_STAT_COLUMN_NAME))-1) << (COLUMN_STAT_COLUMN_NAME+1); } diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 7f6a00f3c62..2bf9a55f8b1 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -1431,14 +1431,17 @@ static Sys_var_ulong Sys_optimizer_use_condition_selectivity( "for the best execution plan " "Meaning: " "1 - use selectivity of index backed range conditions to calculate " - "cardinality of the partial join if the last joined table is " - "accessed by full table scan or an index scan " + "the cardinality of a partial join if the last joined table is " + "accessed by full table scan or an index scan, " "2 - use selectivity of index backed range conditions to calculate " - "cardinality of the partial join in any case " + "the cardinality of a partial join in any case, " "3 - additionally always use selectivity of range conditions that are " - "not backed by any index to calculate cardinality of the partial join", + "not backed by any index to calculate the cardinality of a partial join, " + "4 - use histograms to calculate selectivity of range conditions that " + "are not backed by any index to calculate the cardinality of " + "a partial join.", SESSION_VAR(optimizer_use_condition_selectivity), CMD_LINE(REQUIRED_ARG), - VALID_RANGE(1, 3), DEFAULT(1), BLOCK_SIZE(1)); + VALID_RANGE(1, 4), DEFAULT(1), BLOCK_SIZE(1)); /** Warns about deprecated value 63 */ static bool fix_optimizer_search_depth(sys_var *self, THD *thd, @@ -3767,6 +3770,13 @@ static Sys_var_enum Sys_optimizer_use_stat_tables( SESSION_VAR(use_stat_tables), CMD_LINE(REQUIRED_ARG), use_stat_tables_modes, DEFAULT(0)); +static Sys_var_ulong Sys_histogram_size( + "histogram_size", + "Number of bytes used for a histogram. " + "If set to 0, no histograms are created by ANALYZE.", + SESSION_VAR(histogram_size), CMD_LINE(REQUIRED_ARG), + VALID_RANGE(0, 255), DEFAULT(0), BLOCK_SIZE(1)); + static Sys_var_mybool Sys_no_thread_alarm( "debug_no_thread_alarm", "Disable system thread alarm calls. Disabling it may be useful " diff --git a/sql/table.cc b/sql/table.cc index e4dc2adef64..eb693170cb2 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -432,6 +432,8 @@ void TABLE_SHARE::destroy() free_root(&stats_cb.mem_root, MYF(0)); stats_cb.stats_can_be_read= FALSE; stats_cb.stats_is_read= FALSE; + stats_cb.histograms_can_be_read= FALSE; + stats_cb.histograms_are_read= FALSE; if (tmp_table == NO_TMP_TABLE) mysql_mutex_unlock(&LOCK_ha_data); diff --git a/sql/table.h b/sql/table.h index 85b31af8a77..62daa46c9d3 100644 --- a/sql/table.h +++ b/sql/table.h @@ -573,7 +573,9 @@ struct TABLE_STATISTICS_CB Table_statistics *table_stats; /* Structure to access the statistical data */ 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 */ + from statistical tables */ + bool histograms_can_be_read; + bool histograms_are_read; }; @@ -1200,6 +1202,7 @@ public: #endif uint max_keys; /* Size of allocated key_info array. */ bool stats_is_read; /* Persistent statistics is read for the table */ + bool histograms_are_read; MDL_ticket *mdl_ticket; void init(THD *thd, TABLE_LIST *tl); From 905549863454647b6070e23b7cf5fc1394f92750 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 30 Mar 2013 15:37:21 -0700 Subject: [PATCH 06/37] Fixed several bugs for mwl #253. One of them is quite serious: the function table_cond_selectivity used the TABLE_REF structure for ref/eq_ref access methods as if they had been filled. In fact these structure are filled after the best execution plan has been chosen. The other bugs happened due to: - an erroneous attempt at get statistics on the result of materialization of a view - incorrect handling of ranges with no left/right limits when calculating selectivity of range conditions on non-indexed columns - lack of cleanup for some newly introduced fields --- mysql-test/r/selectivity.result | 341 +++++++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 341 +++++++++++++++++++++++++ mysql-test/t/selectivity.test | 117 ++++++++- sql/sql_select.cc | 102 ++++++-- sql/sql_statistics.cc | 44 +++- sql/table.cc | 6 + 6 files changed, 914 insertions(+), 37 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index af3f6fdda2d..77a26bc21f1 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -11,6 +11,347 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; +=== Q15 === +create view revenue0 (supplier_no, total_revenue) as +select l_suppkey, sum(l_extendedprice * (1 - l_discount)) +from lineitem +where +l_shipdate >= '1995-08-01' + and l_shipdate < date_add('1995-08-01', interval 90 day) +group by l_suppkey; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using filesort +1 PRIMARY ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where +3 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 268 100.00 Using where; Using temporary; Using filesort +2 SUBQUERY ALL NULL NULL NULL NULL 268 100.00 +4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 268 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where ((`revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`revenue0`.`total_revenue` = (select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`))) order by `dbt3_s001`.`supplier`.`s_suppkey` +select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +s_suppkey s_name s_address s_phone total_revenue +1 Supplier#000000001 N kD4on9OM Ipw3,gf0JBoQDd7tgrzrddZ 27-918-335-1736 729084.7773 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using filesort +1 PRIMARY ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where +3 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 268 0.20 Using where; Using temporary; Using filesort +2 SUBQUERY ALL NULL NULL NULL NULL 268 100.00 +4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 268 0.20 Using where; Using temporary; Using filesort +Warnings: +Note 1003 select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where ((`revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`revenue0`.`total_revenue` = (select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`))) order by `dbt3_s001`.`supplier`.`s_suppkey` +select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +s_suppkey s_name s_address s_phone total_revenue +1 Supplier#000000001 N kD4on9OM Ipw3,gf0JBoQDd7tgrzrddZ 27-918-335-1736 729084.7773 +set optimizer_switch=@save_optimizer_switch; +drop view revenue0; +=== Q16 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 100.00 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 16.67 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +set optimizer_use_condition_selectivity=4; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 16.67 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +=== Q18 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00 +1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00 +1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index +2 MATERIALIZED lineitem index NULL i_l_orderkey_quantity 13 NULL 6005 100.00 Using index +Warnings: +Note 1003 select `dbt3_s001`.`customer`.`c_name` AS `c_name`,`dbt3_s001`.`customer`.`c_custkey` AS `c_custkey`,`dbt3_s001`.`orders`.`o_orderkey` AS `o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE` AS `o_orderdate`,`dbt3_s001`.`orders`.`o_totalprice` AS `o_totalprice`,sum(`dbt3_s001`.`lineitem`.`l_quantity`) AS `sum(l_quantity)` from (select `dbt3_s001`.`lineitem`.`l_orderkey` from `dbt3_s001`.`lineitem` group by `dbt3_s001`.`lineitem`.`l_orderkey` having (sum(`dbt3_s001`.`lineitem`.`l_quantity`) > 250)) join `dbt3_s001`.`customer` join `dbt3_s001`.`orders` join `dbt3_s001`.`lineitem` where ((``.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`lineitem`.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`customer`.`c_custkey` = `dbt3_s001`.`orders`.`o_custkey`)) group by `dbt3_s001`.`customer`.`c_name`,`dbt3_s001`.`customer`.`c_custkey`,`dbt3_s001`.`orders`.`o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE`,`dbt3_s001`.`orders`.`o_totalprice` order by `dbt3_s001`.`orders`.`o_totalprice` desc,`dbt3_s001`.`orders`.`o_orderDATE` +select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +c_name c_custkey o_orderkey o_orderdate o_totalprice sum(l_quantity) +Customer#000000070 70 2567 1998-02-27 263411.29 266 +Customer#000000010 10 4421 1997-04-04 258779.02 255 +Customer#000000082 82 3460 1995-10-03 245976.74 254 +Customer#000000068 68 2208 1995-05-01 245388.06 256 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00 +1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00 +1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index +2 MATERIALIZED lineitem index NULL i_l_orderkey_quantity 13 NULL 6005 100.00 Using index +Warnings: +Note 1003 select `dbt3_s001`.`customer`.`c_name` AS `c_name`,`dbt3_s001`.`customer`.`c_custkey` AS `c_custkey`,`dbt3_s001`.`orders`.`o_orderkey` AS `o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE` AS `o_orderdate`,`dbt3_s001`.`orders`.`o_totalprice` AS `o_totalprice`,sum(`dbt3_s001`.`lineitem`.`l_quantity`) AS `sum(l_quantity)` from (select `dbt3_s001`.`lineitem`.`l_orderkey` from `dbt3_s001`.`lineitem` group by `dbt3_s001`.`lineitem`.`l_orderkey` having (sum(`dbt3_s001`.`lineitem`.`l_quantity`) > 250)) join `dbt3_s001`.`customer` join `dbt3_s001`.`orders` join `dbt3_s001`.`lineitem` where ((``.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`lineitem`.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`customer`.`c_custkey` = `dbt3_s001`.`orders`.`o_custkey`)) group by `dbt3_s001`.`customer`.`c_name`,`dbt3_s001`.`customer`.`c_custkey`,`dbt3_s001`.`orders`.`o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE`,`dbt3_s001`.`orders`.`o_totalprice` order by `dbt3_s001`.`orders`.`o_totalprice` desc,`dbt3_s001`.`orders`.`o_orderDATE` +select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +c_name c_custkey o_orderkey o_orderdate o_totalprice sum(l_quantity) +Customer#000000070 70 2567 1998-02-27 263411.29 266 +Customer#000000010 10 4421 1997-04-04 258779.02 255 +Customer#000000082 82 3460 1995-10-03 245976.74 254 +Customer#000000068 68 2208 1995-05-01 245388.06 256 +=== Q22 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE customer ALL NULL NULL NULL NULL 150 100.00 Using where; Using temporary; Using filesort +4 DEPENDENT SUBQUERY orders ref i_o_custkey i_o_custkey 5 dbt3_s001.customer.c_custkey 15 100.00 Using index +3 SUBQUERY customer ALL NULL NULL NULL NULL 150 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where ((substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and (`dbt3_s001`.`customer`.`c_acctbal` > (select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where ((`dbt3_s001`.`customer`.`c_acctbal` > 0.00) and (substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25'))))) and (not(exists(select 1 from `dbt3_s001`.`orders` where (`dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +cntrycode numcust totacctbal +11 4 29942.58 +19 2 17120.35 +20 1 9091.82 +28 2 14755.5 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE customer ALL NULL NULL NULL NULL 150 100.00 Using where; Using temporary; Using filesort +4 DEPENDENT SUBQUERY orders ref i_o_custkey i_o_custkey 5 dbt3_s001.customer.c_custkey 15 100.00 Using index +3 SUBQUERY customer ALL NULL NULL NULL NULL 150 91.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where ((substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and (`dbt3_s001`.`customer`.`c_acctbal` > (select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where ((`dbt3_s001`.`customer`.`c_acctbal` > 0.00) and (substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25'))))) and (not(exists(select 1 from `dbt3_s001`.`orders` where (`dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +cntrycode numcust totacctbal +11 4 29942.58 +19 2 17120.35 +20 1 9091.82 +28 2 14755.5 +=== Q20 === +set optimizer_use_condition_selectivity=1; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 9ececad3492..6fbff38000d 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -14,6 +14,347 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; +=== Q15 === +create view revenue0 (supplier_no, total_revenue) as +select l_suppkey, sum(l_extendedprice * (1 - l_discount)) +from lineitem +where +l_shipdate >= '1995-08-01' + and l_shipdate < date_add('1995-08-01', interval 90 day) +group by l_suppkey; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier index PRIMARY PRIMARY 4 NULL 10 100.00 +1 PRIMARY ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where +3 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 228 100.00 Using where; Using temporary; Using filesort +2 SUBQUERY ALL NULL NULL NULL NULL 228 100.00 +4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 228 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where ((`revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`revenue0`.`total_revenue` = (select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`))) order by `dbt3_s001`.`supplier`.`s_suppkey` +select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +s_suppkey s_name s_address s_phone total_revenue +1 Supplier#000000001 N kD4on9OM Ipw3,gf0JBoQDd7tgrzrddZ 27-918-335-1736 729084.7773 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY supplier index PRIMARY PRIMARY 4 NULL 10 100.00 +1 PRIMARY ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where +3 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 228 0.14 Using where; Using temporary; Using filesort +2 SUBQUERY ALL NULL NULL NULL NULL 228 100.00 +4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 228 0.14 Using where; Using temporary; Using filesort +Warnings: +Note 1003 select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where ((`revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`revenue0`.`total_revenue` = (select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`))) order by `dbt3_s001`.`supplier`.`s_suppkey` +select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no +and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; +s_suppkey s_name s_address s_phone total_revenue +1 Supplier#000000001 N kD4on9OM Ipw3,gf0JBoQDd7tgrzrddZ 27-918-335-1736 729084.7773 +set optimizer_switch=@save_optimizer_switch; +drop view revenue0; +=== Q16 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 100.00 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 16.67 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +set optimizer_use_condition_selectivity=4; +EXPLAIN EXTENDED select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 16.67 Using where; Using temporary; Using filesort +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; Using index +2 MATERIALIZED supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using where +Warnings: +Note 1003 select `dbt3_s001`.`part`.`p_brand` AS `p_brand`,`dbt3_s001`.`part`.`p_type` AS `p_type`,`dbt3_s001`.`part`.`p_size` AS `p_size`,count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) AS `supplier_cnt` from `dbt3_s001`.`partsupp` join `dbt3_s001`.`part` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`part`.`p_brand` <> 'Brand#11') and (not((`dbt3_s001`.`part`.`p_type` like 'SMALL POLISHED%'))) and (`dbt3_s001`.`part`.`p_size` in (49,37,27,5,40,6,22,8)) and (not(<`dbt3_s001`.`partsupp`.`ps_suppkey`>((`dbt3_s001`.`partsupp`.`ps_suppkey`,`dbt3_s001`.`partsupp`.`ps_suppkey` in ( (select `dbt3_s001`.`supplier`.`s_suppkey` from `dbt3_s001`.`supplier` where (`dbt3_s001`.`supplier`.`s_comment` like '%Customer%Complaints%') ), (`dbt3_s001`.`partsupp`.`ps_suppkey` in on distinct_key where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = ``.`s_suppkey`))))))))) group by `dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` order by count(distinct `dbt3_s001`.`partsupp`.`ps_suppkey`) desc,`dbt3_s001`.`part`.`p_brand`,`dbt3_s001`.`part`.`p_type`,`dbt3_s001`.`part`.`p_size` +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey +and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) +and ps_suppkey not in (select s_suppkey from supplier +where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; +p_brand p_type p_size supplier_cnt +Brand#21 MEDIUM ANODIZED TIN 8 4 +Brand#22 PROMO PLATED TIN 5 4 +Brand#24 MEDIUM BURNISHED NICKEL 6 4 +Brand#24 SMALL ANODIZED STEEL 40 4 +Brand#32 MEDIUM BURNISHED BRASS 49 4 +Brand#33 MEDIUM POLISHED BRASS 49 4 +Brand#41 STANDARD BRUSHED NICKEL 40 4 +Brand#44 PROMO POLISHED STEEL 5 4 +Brand#45 PROMO ANODIZED BRASS 22 4 +Brand#53 STANDARD BRUSHED STEEL 27 4 +Brand#54 MEDIUM POLISHED BRASS 22 4 +Brand#54 STANDARD ANODIZED BRASS 22 4 +Brand#13 LARGE BRUSHED STEEL 8 2 +Brand#25 ECONOMY BURNISHED COPPER 27 2 +Brand#44 STANDARD PLATED TIN 37 1 +Brand#51 ECONOMY POLISHED STEEL 49 1 +=== Q18 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00 +1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00 +1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index +2 MATERIALIZED lineitem index NULL PRIMARY 8 NULL 6005 100.00 +Warnings: +Note 1003 select `dbt3_s001`.`customer`.`c_name` AS `c_name`,`dbt3_s001`.`customer`.`c_custkey` AS `c_custkey`,`dbt3_s001`.`orders`.`o_orderkey` AS `o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE` AS `o_orderdate`,`dbt3_s001`.`orders`.`o_totalprice` AS `o_totalprice`,sum(`dbt3_s001`.`lineitem`.`l_quantity`) AS `sum(l_quantity)` from (select `dbt3_s001`.`lineitem`.`l_orderkey` from `dbt3_s001`.`lineitem` group by `dbt3_s001`.`lineitem`.`l_orderkey` having (sum(`dbt3_s001`.`lineitem`.`l_quantity`) > 250)) join `dbt3_s001`.`customer` join `dbt3_s001`.`orders` join `dbt3_s001`.`lineitem` where ((``.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`lineitem`.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`customer`.`c_custkey` = `dbt3_s001`.`orders`.`o_custkey`)) group by `dbt3_s001`.`customer`.`c_name`,`dbt3_s001`.`customer`.`c_custkey`,`dbt3_s001`.`orders`.`o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE`,`dbt3_s001`.`orders`.`o_totalprice` order by `dbt3_s001`.`orders`.`o_totalprice` desc,`dbt3_s001`.`orders`.`o_orderDATE` +select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +c_name c_custkey o_orderkey o_orderdate o_totalprice sum(l_quantity) +Customer#000000070 70 2567 1998-02-27 263411.29 266 +Customer#000000010 10 4421 1997-04-04 258779.02 255 +Customer#000000082 82 3460 1995-10-03 245976.74 254 +Customer#000000068 68 2208 1995-05-01 245388.06 256 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort +1 PRIMARY eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00 +1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00 +1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index +2 MATERIALIZED lineitem index NULL PRIMARY 8 NULL 6005 100.00 +Warnings: +Note 1003 select `dbt3_s001`.`customer`.`c_name` AS `c_name`,`dbt3_s001`.`customer`.`c_custkey` AS `c_custkey`,`dbt3_s001`.`orders`.`o_orderkey` AS `o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE` AS `o_orderdate`,`dbt3_s001`.`orders`.`o_totalprice` AS `o_totalprice`,sum(`dbt3_s001`.`lineitem`.`l_quantity`) AS `sum(l_quantity)` from (select `dbt3_s001`.`lineitem`.`l_orderkey` from `dbt3_s001`.`lineitem` group by `dbt3_s001`.`lineitem`.`l_orderkey` having (sum(`dbt3_s001`.`lineitem`.`l_quantity`) > 250)) join `dbt3_s001`.`customer` join `dbt3_s001`.`orders` join `dbt3_s001`.`lineitem` where ((``.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`lineitem`.`l_orderkey` = `dbt3_s001`.`orders`.`o_orderkey`) and (`dbt3_s001`.`customer`.`c_custkey` = `dbt3_s001`.`orders`.`o_custkey`)) group by `dbt3_s001`.`customer`.`c_name`,`dbt3_s001`.`customer`.`c_custkey`,`dbt3_s001`.`orders`.`o_orderkey`,`dbt3_s001`.`orders`.`o_orderDATE`,`dbt3_s001`.`orders`.`o_totalprice` order by `dbt3_s001`.`orders`.`o_totalprice` desc,`dbt3_s001`.`orders`.`o_orderDATE` +select +c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where +o_orderkey in (select l_orderkey from lineitem +group by l_orderkey having sum(l_quantity) > 250) +and c_custkey = o_custkey +and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; +c_name c_custkey o_orderkey o_orderdate o_totalprice sum(l_quantity) +Customer#000000070 70 2567 1998-02-27 263411.29 266 +Customer#000000010 10 4421 1997-04-04 258779.02 255 +Customer#000000082 82 3460 1995-10-03 245976.74 254 +Customer#000000068 68 2208 1995-05-01 245388.06 256 +=== Q22 === +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE customer ALL NULL NULL NULL NULL 150 100.00 Using where; Using temporary; Using filesort +4 DEPENDENT SUBQUERY orders ref i_o_custkey i_o_custkey 5 dbt3_s001.customer.c_custkey 15 100.00 Using index +3 SUBQUERY customer ALL NULL NULL NULL NULL 150 100.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where ((substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and (`dbt3_s001`.`customer`.`c_acctbal` > (select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where ((`dbt3_s001`.`customer`.`c_acctbal` > 0.00) and (substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25'))))) and (not(exists(select 1 from `dbt3_s001`.`orders` where (`dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +cntrycode numcust totacctbal +11 4 29942.58 +19 2 17120.35 +20 1 9091.82 +28 2 14755.5 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE customer ALL NULL NULL NULL NULL 150 100.00 Using where; Using temporary; Using filesort +4 DEPENDENT SUBQUERY orders ref i_o_custkey i_o_custkey 5 dbt3_s001.customer.c_custkey 15 100.00 Using index +3 SUBQUERY customer ALL NULL NULL NULL NULL 150 91.00 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where ((substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and (`dbt3_s001`.`customer`.`c_acctbal` > (select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where ((`dbt3_s001`.`customer`.`c_acctbal` > 0.00) and (substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25'))))) and (not(exists(select 1 from `dbt3_s001`.`orders` where (`dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( +select substr(c_phone, 1, 2) as cntrycode, c_acctbal +from customer +where +substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') +and c_acctbal > (select avg(c_acctbal) from customer +where c_acctbal > 0.00 +and substr(c_phone, 1, 2) in +('10', '20', '14', '19', '11', '28', '25')) +and not exists (select * from orders where o_custkey = c_custkey) +) as vip +group by cntrycode +order by cntrycode; +cntrycode numcust totacctbal +11 4 29942.58 +19 2 17120.35 +20 1 9091.82 +28 2 14755.5 +=== Q20 === +set optimizer_use_condition_selectivity=1; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 77089271cdd..5ec24d5f66e 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -31,6 +31,119 @@ customer, lineitem, nation, orders, part, partsupp, region, supplier; --enable_result_log --enable_query_log + +--echo === Q15 === + +create view revenue0 (supplier_no, total_revenue) as + select l_suppkey, sum(l_extendedprice * (1 - l_discount)) + from lineitem + where + l_shipdate >= '1995-08-01' + and l_shipdate < date_add('1995-08-01', interval 90 day) + group by l_suppkey; + +let $Q15= +select s_suppkey, s_name, s_address, s_phone, total_revenue +from supplier, revenue0 +where s_suppkey = supplier_no + and total_revenue = (select max(total_revenue) from revenue0) +order by s_suppkey; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; + +set optimizer_use_condition_selectivity=1; +eval EXPLAIN EXTENDED $Q15; +eval $Q15; + +set optimizer_use_condition_selectivity=3; +eval EXPLAIN EXTENDED $Q15; +eval $Q15; + +set optimizer_switch=@save_optimizer_switch; + +drop view revenue0; + + +--echo === Q16 === + +let $Q16= +select p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt +from partsupp, part +where p_partkey = ps_partkey + and p_brand <> 'Brand#11' + and p_type not like 'SMALL POLISHED%' + and p_size in (49, 37, 27, 5, 40, 6, 22, 8) + and ps_suppkey not in (select s_suppkey from supplier + where s_comment like '%Customer%Complaints%') +group by p_brand, p_type, p_size +order by supplier_cnt desc, p_brand, p_type, p_size; + +set optimizer_use_condition_selectivity=1; +eval EXPLAIN EXTENDED $Q16; +eval $Q16; + +set optimizer_use_condition_selectivity=3; +eval EXPLAIN EXTENDED $Q16; +eval $Q16; + +set optimizer_use_condition_selectivity=4; +eval EXPLAIN EXTENDED $Q16; +eval $Q16; + + +--echo === Q18 === + +let $Q18= +select + c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) +from customer, orders, lineitem +where + o_orderkey in (select l_orderkey from lineitem + group by l_orderkey having sum(l_quantity) > 250) + and c_custkey = o_custkey + and o_orderkey = l_orderkey +group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice +order by o_totalprice desc, o_orderdate; + +set optimizer_use_condition_selectivity=1; +eval EXPLAIN EXTENDED $Q18; +eval $Q18; + +set optimizer_use_condition_selectivity=3; +eval EXPLAIN EXTENDED $Q18; +eval $Q18; + + +--echo === Q22 === + +let $Q22= +select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal +from ( + select substr(c_phone, 1, 2) as cntrycode, c_acctbal + from customer + where + substr(c_phone, 1, 2) in ('10', '20', '14', '19', '11', '28', '25') + and c_acctbal > (select avg(c_acctbal) from customer + where c_acctbal > 0.00 + and substr(c_phone, 1, 2) in + ('10', '20', '14', '19', '11', '28', '25')) + and not exists (select * from orders where o_custkey = c_custkey) + ) as vip +group by cntrycode +order by cntrycode; + +set optimizer_use_condition_selectivity=1; +eval EXPLAIN EXTENDED $Q22; +eval $Q22; + +set optimizer_use_condition_selectivity=3; +eval EXPLAIN EXTENDED $Q22; +eval $Q22; + + +--echo === Q20 === + let $Q20= select sql_calc_found_rows s_name, s_address @@ -51,11 +164,11 @@ and n_name = 'UNITED STATES' order by s_name limit 10; +set optimizer_use_condition_selectivity=1; eval EXPLAIN EXTENDED $Q20; eval $Q20; set optimizer_use_condition_selectivity=3; - eval EXPLAIN EXTENDED $Q20; eval $Q20; @@ -66,7 +179,6 @@ flush table part; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); set optimizer_use_condition_selectivity=4; - eval EXPLAIN EXTENDED $Q20; eval $Q20; @@ -79,6 +191,7 @@ ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); eval EXPLAIN EXTENDED $Q20; eval $Q20; + DROP DATABASE dbt3_s001; set histogram_size=@save_histogram_size; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index a73760d4134..ddde1b3f358 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6878,7 +6878,8 @@ double JOIN::get_examined_rows() static double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, - table_map rem_tables, TABLE_REF *ref) + table_map rem_tables, uint keyparts, + uint16 *ref_keyuse_steps) { double sel= 1.0; COND_EQUAL *cond_equal= join->cond_equal; @@ -6886,15 +6887,15 @@ double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, if (!cond_equal || !cond_equal->current_level.elements) return sel; - Item_equal *item_equal; - List_iterator_fast it(cond_equal->current_level); - table_map table_bit= s->table->map; - - if (!s->keyuse) + if (!s->keyuse) return sel; - KEY *key_info= s->get_keyinfo_by_key_no(s->ref.key); - + Item_equal *item_equal; + List_iterator_fast it(cond_equal->current_level); + TABLE *table= s->table; + table_map table_bit= table->map; + POSITION *pos= &join->positions[idx]; + while ((item_equal= it++)) { /* @@ -6916,17 +6917,25 @@ double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, Field *fld= fi.get_curr_field(); if (fld->table->map != table_bit) continue; - if (ref == 0) + if (pos->key == 0) adjust_sel= TRUE; else { uint i; - for (i= 0; i < ref->key_parts; i++) + KEYUSE *keyuse= pos->key; + uint key= keyuse->key; + + for (i= 0; i < keyparts; i++) { - if (fld->field_index == key_info->key_part[i].fieldnr - 1) + uint fldno; + if (is_hash_join_key_no(key)) + fldno= keyuse->keypart; + else + fldno= table->key_info[key].key_part[keyparts-1].fieldnr - 1; + if (fld->field_index == fldno) break; } - if (i == ref->key_parts) + if (i == keyparts) { /* Field fld is included in multiple equality item_equal @@ -6936,11 +6945,14 @@ double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, equal to fld. */ adjust_sel= TRUE; - for (uint j= 0; j < ref->key_parts && adjust_sel; j++) + for (uint j= 0; j < keyparts && adjust_sel; j++) { - if (ref->items[j]->real_item()->type() == Item::FIELD_ITEM) + if (j > 0) + keyuse+= ref_keyuse_steps[j-1]; + Item *ref_item= keyuse->val; + if (ref_item->real_item()->type() == Item::FIELD_ITEM) { - Item_field *field_item= (Item_field *) (ref->items[j]); + Item_field *field_item= (Item_field *) ref_item; if (item_equal->contains(field_item->field)) adjust_sel= FALSE; } @@ -6978,33 +6990,70 @@ static double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, table_map rem_tables) { + uint16 ref_keyuse_steps[MAX_REF_PARTS - 1]; Field *field; TABLE *table= s->table; MY_BITMAP *read_set= table->read_set; double sel= s->table->cond_selectivity; double table_records= table->stat_records(); - TABLE_REF *ref= s->type == JT_REF || s->type == JT_EQ_REF ? &s->ref : NULL; + POSITION *pos= &join->positions[idx]; + uint keyparts= 0; + uint found_part_ref_or_null= 0; /* Discount the selectivity of the access method used to join table s */ if (s->quick && s->quick->index != MAX_KEY) { - if (join->positions[idx].key == 0) + if (pos->key == 0) { sel*= table->quick_rows[s->quick->index]/table_records; } } - else if (ref) + else if (pos->key != 0) { - /* A ref/ access or hash join is used to join table s */ - KEY *key_info= s->get_keyinfo_by_key_no(ref->key); - for (uint i= 0; i < ref->key_parts; i++) + /* A ref/ access or hash join is used to join table */ + KEYUSE *keyuse= pos->key; + KEYUSE *prev_ref_keyuse= keyuse; + uint key= keyuse->key; + do { - if (ref->items[i]->const_item()) + if (!(keyuse->used_tables & (rem_tables | table->map))) { - uint fldno= key_info->key_part[i].fieldnr - 1; - sel*= table->field[fldno]->cond_selectivity; + if (are_tables_local(s, keyuse->val->used_tables())) + { + if (is_hash_join_key_no(key)) + { + if (keyparts == keyuse->keypart) + keyparts++; + } + else + { + if (keyparts == keyuse->keypart && + !(~(keyuse->val->used_tables()) & pos->ref_depend_map) && + !(found_part_ref_or_null & keyuse->optimize)) + { + keyparts++; + found_part_ref_or_null|= keyuse->optimize & ~KEY_OPTIMIZE_EQ; + } + } + if (keyparts > keyuse->keypart) + { + uint fldno; + if (is_hash_join_key_no(key)) + fldno= keyuse->keypart; + else + fldno= table->key_info[key].key_part[keyparts-1].fieldnr - 1; + if (keyuse->val->const_item()) + sel*= table->field[fldno]->cond_selectivity; + if (keyparts > 1) + { + ref_keyuse_steps[keyparts-2]= keyuse - prev_ref_keyuse; + prev_ref_keyuse= keyuse; + } + } + } } - } + keyuse++; + } while (keyuse->table == table && keyuse->key == key); } for (Field **f_ptr=table->field ; (field= *f_ptr) ; f_ptr++) @@ -7024,7 +7073,8 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, } } - sel*= table_multi_eq_cond_selectivity(join, idx, s, rem_tables, ref); + sel*= table_multi_eq_cond_selectivity(join, idx, s, rem_tables, + keyparts, ref_keyuse_steps); return sel; } diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 8c0b2730b02..0f26ca7520a 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3303,6 +3303,18 @@ double get_column_avg_frequency(Field * field) { double res; TABLE *table= field->table; + + /* + Statistics is shared by table instances and is accessed through + the table share. If table->s->field is not set for 'table', then + no column statistics is available for the table . + */ + if (!table->s->field) + { + res= table->stat_records(); + return res; + } + Column_statistics *col_stats= table->s->field[field->field_index]->read_stats; if (!col_stats) @@ -3323,8 +3335,8 @@ double get_column_range_cardinality(Field *field, if (!col_stats) res= table->stat_records(); - else if (min_endp->length == max_endp->length && - !memcmp(min_endp->key, max_endp->key, min_endp->length)) + else if (min_endp && max_endp && min_endp->length == max_endp->length && + !memcmp(min_endp->key, max_endp->key, min_endp->length)) { double avg_frequency= col_stats->get_avg_frequency(); res= avg_frequency; @@ -3346,13 +3358,27 @@ double get_column_range_cardinality(Field *field, { if (col_stats->min_value && col_stats->max_value) { - double sel; - store_key_image_to_rec(field, (uchar *) min_endp->key, min_endp->length); - double min_mp_pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); - store_key_image_to_rec(field, (uchar *) max_endp->key, max_endp->length); - double max_mp_pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); + double sel, min_mp_pos, max_mp_pos; + + if (min_endp) + { + store_key_image_to_rec(field, (uchar *) min_endp->key, + min_endp->length); + min_mp_pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + } + else + min_mp_pos= 0.0; + if (max_endp) + { + store_key_image_to_rec(field, (uchar *) max_endp->key, + max_endp->length); + max_mp_pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + } + else + max_mp_pos= 1.0; + Histogram *hist= &col_stats->histogram; if (hist->get_size() == 0) sel= (max_mp_pos - min_mp_pos); diff --git a/sql/table.cc b/sql/table.cc index eb693170cb2..2adaf5b5bf7 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -3974,6 +3974,7 @@ void TABLE::init(THD *thd, TABLE_LIST *tl) file->ha_start_of_new_statement(); reginfo.impossible_range= 0; created= TRUE; + cond_selectivity= 1.0; /* Catch wrong handling of the auto_increment_field_not_null. */ DBUG_ASSERT(!auto_increment_field_not_null); @@ -3982,6 +3983,11 @@ void TABLE::init(THD *thd, TABLE_LIST *tl) pos_in_table_list= tl; clear_column_bitmaps(); + for (Field **f_ptr= field ; *f_ptr ; f_ptr++) + { + (*f_ptr)->next_equal_field= NULL; + (*f_ptr)->cond_selectivity= 1.0; + } DBUG_ASSERT(key_read == 0); From 9e1ca1053b5e619e1f6c727abdf787dc163ab4e6 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 30 Mar 2013 18:57:07 -0700 Subject: [PATCH 07/37] Added the type of histogram for mwl #253. Introduced double precision height-balanced histograms. --- mysql-test/r/mysqld--help.result | 6 + mysql-test/r/selectivity.result | 65 ++- mysql-test/r/selectivity_innodb.result | 66 ++- mysql-test/r/statistics.result | 465 +++++++++--------- mysql-test/r/system_mysql_db.result | 1 + .../suite/funcs_1/r/is_columns_mysql.result | 4 +- .../sys_vars/r/histogram_type_basic.result | 79 +++ .../sys_vars/t/histogram_type_basic.test | 92 ++++ mysql-test/t/selectivity.test | 24 +- mysql-test/t/statistics.test | 14 + scripts/mysql_system_tables.sql | 2 +- sql/sql_class.h | 1 + sql/sql_statistics.cc | 22 +- sql/sql_statistics.h | 108 +++- sql/sys_vars.cc | 11 + 15 files changed, 695 insertions(+), 265 deletions(-) create mode 100644 mysql-test/suite/sys_vars/r/histogram_type_basic.result create mode 100644 mysql-test/suite/sys_vars/t/histogram_type_basic.test diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index 1804bd1c6fb..13747404733 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -204,6 +204,11 @@ The following options may be given as the first argument: -?, --help Display this help and exit. --histogram-size=# Number of bytes used for a histogram. If set to 0, no histograms are created by ANALYZE. + --histogram-type=name + Specifies type of the histograms created by ANALYZE. + Possible values are: SINGLE_PREC_HB - single precision + height-balanced, DOUBLE_PREC_HB - double precision + height-balanced. --ignore-builtin-innodb Disable initialization of builtin InnoDB plugin --ignore-db-dirs=name @@ -932,6 +937,7 @@ general-log FALSE group-concat-max-len 1024 help TRUE histogram-size 0 +histogram-type SINGLE_PREC_HB ignore-builtin-innodb FALSE ignore-db-dirs init-connect diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index af3f6fdda2d..bdc04bb89b1 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -11,6 +11,7 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; +set @save_histogram_type=@@histogram_type; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -60,6 +61,10 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY +SELECT ((SELECT COUNT(*) FROM part WHERE p_name LIKE 'g%') / +(SELECT COUNT(*) FROM part)) AS sel; +sel +0.0600 set optimizer_use_condition_selectivity=3; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address @@ -111,10 +116,10 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_size=15; -flush table part; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status Table is already up to date +flush table part; set optimizer_use_condition_selectivity=4; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address @@ -164,11 +169,66 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY +set histogram_type='DOUBLE_PREC_HB'; +set histogram_size=30; +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.part analyze status Table is already up to date +flush table part; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_suppkey` = `dbt3_s001`.`supplier`.`s_suppkey`) and (`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set histogram_type='SINGLE_PREC_HB'; set histogram_size=24; -flush table nation; ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.nation analyze status Table is already up to date +flush table nation; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -218,6 +278,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY DROP DATABASE dbt3_s001; +set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 9ececad3492..d90fe9f6379 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -14,6 +14,7 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; +set @save_histogram_type=@@histogram_type; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -63,6 +64,10 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY +SELECT ((SELECT COUNT(*) FROM part WHERE p_name LIKE 'g%') / +(SELECT COUNT(*) FROM part)) AS sel; +sel +0.0600 set optimizer_use_condition_selectivity=3; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address @@ -114,10 +119,10 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_size=15; -flush table part; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status OK +flush table part; set optimizer_use_condition_selectivity=4; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address @@ -168,11 +173,67 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY +set histogram_type='DOUBLE_PREC_HB'; +set histogram_size=30; +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); +Table Op Msg_type Msg_text +dbt3_s001.part analyze status OK +flush table part; +EXPLAIN EXTENDED select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort +1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where +4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where +Warnings: +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_partkey' of SELECT #4 was resolved in SELECT #2 +Note 1276 Field or reference 'dbt3_s001.partsupp.ps_suppkey' of SELECT #4 was resolved in SELECT #2 +Note 1003 select sql_calc_found_rows `dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address` from `dbt3_s001`.`supplier` semi join (`dbt3_s001`.`part` join `dbt3_s001`.`partsupp`) join `dbt3_s001`.`nation` where ((`dbt3_s001`.`partsupp`.`ps_partkey` = `dbt3_s001`.`part`.`p_partkey`) and (`dbt3_s001`.`nation`.`n_name` = 'UNITED STATES') and (`dbt3_s001`.`supplier`.`s_nationkey` = `dbt3_s001`.`nation`.`n_nationkey`) and (`dbt3_s001`.`partsupp`.`ps_availqty` > <`dbt3_s001`.`partsupp`.`ps_partkey`,`dbt3_s001`.`partsupp`.`ps_suppkey`>((select (0.5 * sum(`dbt3_s001`.`lineitem`.`l_quantity`)) from `dbt3_s001`.`lineitem` where ((`dbt3_s001`.`lineitem`.`l_partkey` = `dbt3_s001`.`partsupp`.`ps_partkey`) and (`dbt3_s001`.`lineitem`.`l_suppkey` = `dbt3_s001`.`partsupp`.`ps_suppkey`) and (`dbt3_s001`.`lineitem`.`l_shipDATE` >= (cast('1993-01-01' as date))) and (`dbt3_s001`.`lineitem`.`l_shipDATE` < ((cast('1993-01-01' as date) + interval '1' year))))))) and (`dbt3_s001`.`part`.`p_name` like 'g%')) order by `dbt3_s001`.`supplier`.`s_name` limit 10 +select sql_calc_found_rows +s_name, s_address +from supplier, nation +where s_suppkey in (select ps_suppkey from partsupp +where ps_partkey in (select p_partkey from part +where p_name like 'g%') +and ps_availqty > +(select 0.5 * sum(l_quantity) +from lineitem +where l_partkey = ps_partkey +and l_suppkey = ps_suppkey +and l_shipdate >= date('1993-01-01') +and l_shipdate < date('1993-01-01') + +interval '1' year )) +and s_nationkey = n_nationkey +and n_name = 'UNITED STATES' +order by s_name +limit 10; +s_name s_address +Supplier#000000010 Saygah3gYWMp72i PY +set histogram_type='SINGLE_PREC_HB'; set histogram_size=24; -flush table nation; ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.nation analyze status OK +flush table nation; EXPLAIN EXTENDED select sql_calc_found_rows s_name, s_address from supplier, nation @@ -223,6 +284,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY DROP DATABASE dbt3_s001; +set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 2abff4416c9..2289bda7889 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -64,13 +64,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -87,8 +87,8 @@ COUNT(*) 40 SELECT * FROM mysql.column_stats 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 hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL 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)", @@ -99,8 +99,8 @@ MIN(t1.a) MAX(t1.a) NULLS_RATIO(t1.a) AVG_FREQUENCY(t1.a) 0 49 0.2000 1.0000 SELECT * FROM mysql.column_stats 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 hist_size histogram -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL 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)", @@ -111,8 +111,8 @@ MIN(t1.b) MAX(t1.b) NULLS_RATIO(t1.b) AVG_FREQUENCY(t1.b) vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 SELECT * FROM mysql.column_stats 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 hist_size histogram -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL 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)", @@ -123,8 +123,8 @@ MIN(t1.c) MAX(t1.c) NULLS_RATIO(t1.c) AVG_FREQUENCY(t1.c) aaaa dddddddd 0.1250 7.0000 SELECT * FROM mysql.column_stats 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 hist_size histogram -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL 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)", @@ -135,8 +135,8 @@ 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 mysql.column_stats 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 hist_size histogram -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL 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)", @@ -224,7 +224,26 @@ test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 4 009393FF test t1 e 0.01 0.112 0.2250 6.2000 4 000564E1 test t1 f 1 5 0.2000 6.4000 4 3F7FBFBF DELETE FROM mysql.column_stats; +set histogram_size=8; +set histogram_type='DOUBLE_PREC_HB'; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +SELECT db_name, table_name, column_name, +min_value, max_value, +nulls_ratio, avg_frequency, +hist_size, HEX(histogram) +FROM mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size HEX(histogram) +test t1 a 0 49 0.0000 1.0000 8 052F4363F4A1F9D0 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 8 0000FF3FFFBFFFFF +test t1 c aaaa dddddddd 0.1250 7.0000 8 00005555AAAAFFFF +test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 8 000026942694FFFF +test t1 e 0.01 0.112 0.2250 6.2000 8 000005056464E1E1 +test t1 f 1 5 0.2000 6.4000 8 FF3FFF7FFFBFFFBF +DELETE FROM mysql.column_stats; set histogram_size= 0; +set histogram_type=default; ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status Table is already up to date @@ -260,16 +279,16 @@ db_name table_name cardinality test t1 40 test t3 17 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL -test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL -test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -289,16 +308,16 @@ db_name table_name cardinality test s1 40 test t3 17 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test s1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL -test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL -test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test s1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test s1 PRIMARY 1 1.0000 @@ -318,16 +337,16 @@ db_name table_name cardinality test t1 40 test t3 17 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL -test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL -test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t3 a 0 38 0.0000 4.0000 1.0000 0 NULL NULL +test t3 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.1765 18.0714 2.8000 0 NULL NULL +test t3 c aaaa dddddddd 0.1176 6.4000 3.7500 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -346,13 +365,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -387,13 +406,13 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`y`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 y 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 y 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL ALTER TABLE t1 CHANGE COLUMN x b varchar(32), CHANGE COLUMN y e double; SHOW CREATE TABLE t1; @@ -412,13 +431,13 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL ALTER TABLE t1 RENAME TO s1, CHANGE COLUMN b x varchar(32); SHOW CREATE TABLE s1; Table Create Table @@ -439,13 +458,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test s1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test s1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test s1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test s1 x vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test s1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test s1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test s1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test s1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test s1 PRIMARY 1 1.0000 @@ -477,13 +496,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -512,12 +531,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -541,12 +560,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -557,13 +576,13 @@ 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_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -598,12 +617,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`x`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -627,12 +646,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -646,13 +665,13 @@ LOAD DATA INFILE 'MYSQLTEST_VARDIR/tmp/save_index_stats' INTO TABLE mysql.index_stats FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n'; SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -680,12 +699,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -743,12 +762,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -757,13 +776,13 @@ 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_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b NULL NULL 1.0000 NULL NULL 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b NULL NULL 1.0000 NULL NULL 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -780,13 +799,13 @@ 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_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -812,12 +831,12 @@ t1 CREATE TABLE `t1` ( KEY `idx3` (`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -842,12 +861,12 @@ t1 CREATE TABLE `t1` ( KEY `idx4` (`e`,`b`,`d`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -856,13 +875,13 @@ 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_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -884,7 +903,7 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency ANALYZE TABLE t1 PERSISTENT FOR COLUMNS(c,e,b) INDEXES(idx2,idx4); @@ -894,10 +913,10 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 idx2 1 7.0000 @@ -934,13 +953,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -964,19 +983,19 @@ db_name table_name cardinality test t1 40 test t2 40 SELECT * FROM mysql.column_stats ORDER BY column_name; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats ORDER BY index_name, prefix_arity, table_name; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 @@ -1008,13 +1027,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t2 40 SELECT * FROM mysql.column_stats ORDER BY column_name; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t2 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 17.1250 6.4000 0 NULL NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats ORDER BY index_name, prefix_arity, table_name; db_name table_name index_name prefix_arity avg_frequency test t2 PRIMARY 1 1.0000 @@ -1144,12 +1163,12 @@ MODIFY COLUMN b text, ADD INDEX idx1 (b(4), e), ADD INDEX idx4 (e, b(4), d); SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t2 idx3 1 8.5000 @@ -1165,18 +1184,18 @@ ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status OK SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t2 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t2 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t2 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t2 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t2 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t2 idx3 1 8.5000 @@ -1209,7 +1228,7 @@ mysql.column_stats analyze status OK SELECT * FROM mysql.table_stats; db_name table_name cardinality SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency set use_stat_tables='never'; @@ -1220,13 +1239,13 @@ SELECT * FROM mysql.table_stats; db_name table_name cardinality test t1 40 SELECT * FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size histogram -test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL -test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL -test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL -test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL -test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL -test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 0 49 0.0000 4.0000 1.0000 0 NULL NULL +test t1 c aaaa dddddddd 0.1250 6.6571 7.0000 0 NULL NULL +test t1 d 1989-03-12 1999-07-23 0.1500 3.0000 8.5000 0 NULL NULL +test t1 e 0.01 0.112 0.2250 8.0000 6.2000 0 NULL NULL +test t1 f 1 5 0.2000 1.0000 6.4000 0 NULL NULL +test t1 b NULL NULL 0.2000 17.1250 NULL NULL NULL NULL SELECT * FROM mysql.index_stats; db_name table_name index_name prefix_arity avg_frequency test t1 PRIMARY 1 1.0000 diff --git a/mysql-test/r/system_mysql_db.result b/mysql-test/r/system_mysql_db.result index 4ceedffa5cb..ec350b03e1b 100644 --- a/mysql-test/r/system_mysql_db.result +++ b/mysql-test/r/system_mysql_db.result @@ -287,6 +287,7 @@ column_stats CREATE TABLE `column_stats` ( `avg_length` decimal(12,4) DEFAULT NULL, `avg_frequency` decimal(12,4) DEFAULT NULL, `hist_size` tinyint(3) unsigned DEFAULT NULL, + `hist_type` enum('SINGLE_PREC_HB','DOUBLE_PREC_HB') COLLATE utf8_bin DEFAULT NULL, `histogram` varbinary(255) DEFAULT NULL, PRIMARY KEY (`db_name`,`table_name`,`column_name`) ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_bin COMMENT='Statistics on Columns' 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 bcd9c14f307..5bd4e176ea1 100644 --- a/mysql-test/suite/funcs_1/r/is_columns_mysql.result +++ b/mysql-test/suite/funcs_1/r/is_columns_mysql.result @@ -13,8 +13,9 @@ def mysql column_stats avg_frequency 8 NULL YES decimal NULL NULL 12 4 NULL NULL def mysql column_stats avg_length 7 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references def mysql column_stats column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references def mysql column_stats db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI select,insert,update,references -def mysql column_stats histogram 10 NULL YES varbinary 255 255 NULL NULL NULL NULL NULL varbinary(255) select,insert,update,references +def mysql column_stats histogram 11 NULL YES varbinary 255 255 NULL NULL NULL NULL NULL varbinary(255) select,insert,update,references def mysql column_stats hist_size 9 NULL YES tinyint NULL NULL 3 0 NULL NULL NULL tinyint(3) unsigned select,insert,update,references +def mysql column_stats hist_type 10 NULL YES enum 14 42 NULL NULL NULL utf8 utf8_bin enum('SINGLE_PREC_HB','DOUBLE_PREC_HB') select,insert,update,references def mysql column_stats max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references def mysql column_stats min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) select,insert,update,references def mysql column_stats nulls_ratio 6 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) select,insert,update,references @@ -332,6 +333,7 @@ NULL mysql column_stats nulls_ratio decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_length decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_frequency decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats hist_size tinyint NULL NULL NULL NULL tinyint(3) unsigned +3.0000 mysql column_stats hist_type enum 14 42 utf8 utf8_bin enum('SINGLE_PREC_HB','DOUBLE_PREC_HB') 1.0000 mysql column_stats histogram varbinary 255 255 NULL NULL varbinary(255) 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) diff --git a/mysql-test/suite/sys_vars/r/histogram_type_basic.result b/mysql-test/suite/sys_vars/r/histogram_type_basic.result new file mode 100644 index 00000000000..f688a2a15fd --- /dev/null +++ b/mysql-test/suite/sys_vars/r/histogram_type_basic.result @@ -0,0 +1,79 @@ +SET @start_global_value = @@global.histogram_type; +SELECT @start_global_value; +@start_global_value +SINGLE_PREC_HB +SET @start_session_value = @@session.histogram_type; +SELECT @start_session_value; +@start_session_value +SINGLE_PREC_HB +SET @@global.histogram_type = 1; +SET @@global.histogram_type = DEFAULT; +SELECT @@global.histogram_type; +@@global.histogram_type +SINGLE_PREC_HB +SET @@global.histogram_type = 0; +SELECT @@global.histogram_type; +@@global.histogram_type +SINGLE_PREC_HB +SET @@global.histogram_type = 1; +SELECT @@global.histogram_type; +@@global.histogram_type +DOUBLE_PREC_HB +SET @@global.histogram_type = SINGLE_PREC_HB; +SELECT @@global.histogram_type; +@@global.histogram_type +SINGLE_PREC_HB +SET @@global.histogram_type = DOUBLE_PREC_HB; +SELECT @@global.histogram_type; +@@global.histogram_type +DOUBLE_PREC_HB +SET @@session.histogram_type = 0; +SELECT @@session.histogram_type; +@@session.histogram_type +SINGLE_PREC_HB +SET @@session.histogram_type = 1; +SELECT @@session.histogram_type; +@@session.histogram_type +DOUBLE_PREC_HB +SET @@session.histogram_type = SINGLE_PREC_HB; +SELECT @@session.histogram_type; +@@session.histogram_type +SINGLE_PREC_HB +SET @@session.histogram_type = DOUBLE_PREC_HB; +SELECT @@session.histogram_type; +@@session.histogram_type +DOUBLE_PREC_HB +set sql_mode=TRADITIONAL; +SET @@global.histogram_type = 10; +ERROR 42000: Variable 'histogram_type' can't be set to the value of '10' +SET @@global.histogram_type = -1024; +ERROR 42000: Variable 'histogram_type' can't be set to the value of '-1024' +SET @@global.histogram_type = 2.4; +ERROR 42000: Incorrect argument type to variable 'histogram_type' +SET @@global.histogram_type = OFF; +ERROR 42000: Variable 'histogram_type' can't be set to the value of 'OFF' +SET @@session.histogram_type = 10; +ERROR 42000: Variable 'histogram_type' can't be set to the value of '10' +SET @@session.histogram_type = -2; +ERROR 42000: Variable 'histogram_type' can't be set to the value of '-2' +SET @@session.histogram_type = 1.2; +ERROR 42000: Incorrect argument type to variable 'histogram_type' +SET @@session.histogram_type = ON; +ERROR 42000: Variable 'histogram_type' can't be set to the value of 'ON' +SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='histogram_type'; +VARIABLE_NAME VARIABLE_VALUE +HISTOGRAM_TYPE DOUBLE_PREC_HB +SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='histogram_type'; +VARIABLE_NAME VARIABLE_VALUE +HISTOGRAM_TYPE DOUBLE_PREC_HB +SET @@global.histogram_type = @start_global_value; +SELECT @@global.histogram_type; +@@global.histogram_type +SINGLE_PREC_HB +SET @@session.histogram_type = @start_session_value; +SELECT @@session.histogram_type; +@@session.histogram_type +SINGLE_PREC_HB +set sql_mode=''; diff --git a/mysql-test/suite/sys_vars/t/histogram_type_basic.test b/mysql-test/suite/sys_vars/t/histogram_type_basic.test new file mode 100644 index 00000000000..bf1ef5ef700 --- /dev/null +++ b/mysql-test/suite/sys_vars/t/histogram_type_basic.test @@ -0,0 +1,92 @@ +--source include/load_sysvars.inc + +############################################################# +# Save initial value # +############################################################# + +SET @start_global_value = @@global.histogram_type; +SELECT @start_global_value; +SET @start_session_value = @@session.histogram_type; +SELECT @start_session_value; + +############################################################## +# Display the DEFAULT value of histogram_type # +############################################################## + +SET @@global.histogram_type = 1; +SET @@global.histogram_type = DEFAULT; +SELECT @@global.histogram_type; + +################################################################################# +# Change the value of histogram_type to a valid value for GLOBAL Scope # +################################################################################# + +SET @@global.histogram_type = 0; +SELECT @@global.histogram_type; +SET @@global.histogram_type = 1; +SELECT @@global.histogram_type; + +SET @@global.histogram_type = SINGLE_PREC_HB; +SELECT @@global.histogram_type; +SET @@global.histogram_type = DOUBLE_PREC_HB; +SELECT @@global.histogram_type; + +################################################################################### +# Change the value of histogram_type to a valid value for SESSION Scope # +################################################################################### + +SET @@session.histogram_type = 0; +SELECT @@session.histogram_type; +SET @@session.histogram_type = 1; +SELECT @@session.histogram_type; + +SET @@session.histogram_type = SINGLE_PREC_HB; +SELECT @@session.histogram_type; +SET @@session.histogram_type = DOUBLE_PREC_HB; +SELECT @@session.histogram_type; + +#################################################################### +# Change the value of histogram_type to an invalid value # +#################################################################### + +set sql_mode=TRADITIONAL; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.histogram_type = 10; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.histogram_type = -1024; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@global.histogram_type = 2.4; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@global.histogram_type = OFF; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.histogram_type = 10; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.histogram_type = -2; +--Error ER_WRONG_TYPE_FOR_VAR +SET @@session.histogram_type = 1.2; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.histogram_type = ON; + +############################################################################### +# Check if the value in GLOBAL & SESSION Tables matches value in variable # +############################################################################### + +SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES +WHERE VARIABLE_NAME='histogram_type'; + +SELECT * FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='histogram_type'; + +#################################### +# Restore initial value # +#################################### + +SET @@global.histogram_type = @start_global_value; +SELECT @@global.histogram_type; +SET @@session.histogram_type = @start_session_value; +SELECT @@session.histogram_type; +set sql_mode=''; + +##################################################### +# END OF histogram_type TESTS # +##################################################### \ No newline at end of file diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 77089271cdd..94d02eec484 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -17,6 +17,7 @@ use dbt3_s001; set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; +set @save_histogram_type=@@histogram_type; --disable_query_log --disable_result_log @@ -54,6 +55,9 @@ limit 10; eval EXPLAIN EXTENDED $Q20; eval $Q20; +SELECT ((SELECT COUNT(*) FROM part WHERE p_name LIKE 'g%') / + (SELECT COUNT(*) FROM part)) AS sel; + set optimizer_use_condition_selectivity=3; eval EXPLAIN EXTENDED $Q20; @@ -61,26 +65,38 @@ eval $Q20; set histogram_size=15; -flush table part; - ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); +flush table part; + set optimizer_use_condition_selectivity=4; eval EXPLAIN EXTENDED $Q20; eval $Q20; +set histogram_type='DOUBLE_PREC_HB'; +set histogram_size=30; + +ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); + +flush table part; + +eval EXPLAIN EXTENDED $Q20; +eval $Q20; + +set histogram_type='SINGLE_PREC_HB'; set histogram_size=24; -flush table nation; - ANALYZE TABLE nation PERSISTENT FOR COLUMNS(n_name) INDEXES(); +flush table nation; + eval EXPLAIN EXTENDED $Q20; eval $Q20; DROP DATABASE dbt3_s001; +set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 65412d849ed..2488e511bab 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -178,7 +178,21 @@ SELECT db_name, table_name, column_name, FROM mysql.column_stats; DELETE FROM mysql.column_stats; + +set histogram_size=8; +set histogram_type='DOUBLE_PREC_HB'; +ANALYZE TABLE t1; + +SELECT db_name, table_name, column_name, + min_value, max_value, + nulls_ratio, avg_frequency, + hist_size, HEX(histogram) + FROM mysql.column_stats; + +DELETE FROM mysql.column_stats; + set histogram_size= 0; +set histogram_type=default; ANALYZE TABLE t1; diff --git a/scripts/mysql_system_tables.sql b/scripts/mysql_system_tables.sql index 6a54f339cd0..9872da88cff 100644 --- a/scripts/mysql_system_tables.sql +++ b/scripts/mysql_system_tables.sql @@ -108,6 +108,6 @@ set @had_proxies_priv_table= @@warning_count != 0; CREATE TABLE IF NOT EXISTS table_stats (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_stats (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, hist_size tinyint unsigned, histogram varbinary(255), 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_stats (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, hist_size tinyint unsigned, hist_type enum('SINGLE_PREC_HB','DOUBLE_PREC_HB'), histogram varbinary(255), 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_stats (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/sql_class.h b/sql/sql_class.h index 2844cab9b4e..0cca72d7d1e 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -502,6 +502,7 @@ typedef struct system_variables ulong optimizer_use_condition_selectivity; ulong use_stat_tables; ulong histogram_size; + ulong histogram_type; 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 8c0b2730b02..6e63ae1858f 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -928,6 +928,9 @@ public: case COLUMN_STAT_HIST_SIZE: stat_field->store(table_field->collected_stats->histogram.get_size()); break; + case COLUMN_STAT_HIST_TYPE: + stat_field->store(table_field->collected_stats->histogram.get_type()); + break; case COLUMN_STAT_HISTOGRAM: const char * col_histogram= (const char *) (table_field->collected_stats->histogram.get_values()); @@ -971,7 +974,7 @@ public: char buff[MAX_FIELD_WIDTH]; String val(buff, sizeof(buff), &my_charset_utf8_bin); - for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_HIST_SIZE; i++) + for (uint i= COLUMN_STAT_MIN_VALUE; i <= COLUMN_STAT_HIST_TYPE; i++) { Field *stat_field= stat_table->field[i]; @@ -1007,6 +1010,10 @@ public: case COLUMN_STAT_HIST_SIZE: table_field->read_stats->histogram.set_size(stat_field->val_int()); break; + case COLUMN_STAT_HIST_TYPE: + Histogram_type hist_type= (Histogram_type) (stat_field->val_int()); + table_field->read_stats->histogram.set_type(hist_type); + break; } } } @@ -1238,7 +1245,7 @@ class Histogram_builder Field *min_value; Field *max_value; Histogram *histogram; - uint hist_size; + uint hist_width; double bucket_capacity; uint curr_bucket; ulonglong count; @@ -1252,8 +1259,8 @@ public: min_value= col_stats->min_value; max_value= col_stats->max_value; histogram= &col_stats->histogram; - hist_size= histogram->get_size(); - bucket_capacity= (double) records / (hist_size + 1); + hist_width= histogram->get_width(); + bucket_capacity= (double) records / (hist_width + 1); curr_bucket= 0; count= 0; count_distinct= 0; @@ -1265,7 +1272,7 @@ public: { count_distinct++; count+= elem_cnt; - if (curr_bucket == hist_size) + if (curr_bucket == hist_width) return 0; if (count > bucket_capacity * (curr_bucket + 1)) { @@ -1273,7 +1280,7 @@ public: histogram->set_value(curr_bucket, column->middle_point_pos(min_value, max_value)); curr_bucket++; - while (curr_bucket != hist_size && + while (curr_bucket != hist_width && count > bucket_capacity * (curr_bucket + 1)) { histogram->set_prev_value(curr_bucket); @@ -1794,6 +1801,7 @@ int alloc_statistics_for_table(THD* thd, TABLE *table) columns++; } uint hist_size= thd->variables.histogram_size; + Histogram_type hist_type= (Histogram_type) (thd->variables.histogram_type); uchar *histogram= NULL; if (hist_size > 0) histogram= (uchar *) alloc_root(&table->mem_root, hist_size * columns); @@ -1818,6 +1826,7 @@ int alloc_statistics_for_table(THD* thd, TABLE *table) if (bitmap_is_set(table->read_set, (*field_ptr)->field_index)) { column_stats->histogram.set_size(hist_size); + column_stats->histogram.set_type(hist_type); column_stats->histogram.set_values(histogram); histogram+= hist_size; } @@ -2200,6 +2209,7 @@ void Column_statistics_collected::finish(ha_rows rows) set_not_null(COLUMN_STAT_HIST_SIZE); if (hist_size && distincts) { + set_not_null(COLUMN_STAT_HIST_TYPE); histogram.set_values(count_distinct->get_histogram()); set_not_null(COLUMN_STAT_HISTOGRAM); } diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 9a2b5c2433b..b699ec7100a 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -24,6 +24,13 @@ enum enum_use_stat_tables_mode PEFERABLY, } Use_stat_tables_mode; +typedef +enum enum_histogram_type +{ + SINGLE_PREC_HB, + DOUBLE_PREC_HB +} Histogram_type; + enum enum_stat_tables { TABLE_STAT, @@ -59,6 +66,7 @@ enum enum_column_stat_col COLUMN_STAT_AVG_LENGTH, COLUMN_STAT_AVG_FREQUENCY, COLUMN_STAT_HIST_SIZE, + COLUMN_STAT_HIST_TYPE, COLUMN_STAT_HISTOGRAM }; @@ -99,46 +107,74 @@ double get_column_range_cardinality(Field *field, key_range *min_endp, key_range *max_endp); -#define HIST_FACTOR 255 -#define INV_HIST_FACTOR ((double) 1.0 / HIST_FACTOR) - class Histogram { -private: -public: private: + Histogram_type type; uint8 size; - uint8 *values; + uchar *values; + + uint prec_factor() + { + switch (type) { + case SINGLE_PREC_HB: + return ((uint) (1 << 8) - 1); + case DOUBLE_PREC_HB: + return ((uint) (1 << 16) - 1); + } + } + +public: + uint get_width() + { + switch (type) { + case SINGLE_PREC_HB: + return size; + case DOUBLE_PREC_HB: + return size / 2; + } + } + +private: + uint get_value(uint i) + { + switch (type) { + case SINGLE_PREC_HB: + return (uint) (((uint8 *) values)[i]); + case DOUBLE_PREC_HB: + return (uint) (((uint16 *) values)[i]); + } + } uint find_bucket(double pos, bool first) { - uint8 val= (uint8) (pos * HIST_FACTOR); + uint val= (uint) (pos * prec_factor()); int lp= 0; - int rp= size - 1; - int i= 0; - for (int d= size / 2 ; d; d= (rp - lp) / 2) + int rp= get_width() - 1; + uint i= 0; + for (int d= get_width() / 2 ; d; d= (rp - lp) / 2) { i= lp + d; - if (val == values[i]) + if (val == get_value(i)) break; - if (val < values[i]) + if (val < get_value(i)) rp= i; - else if (val > values[i + 1]) + else if (val > get_value(i + 1)) lp= i + 1; else break; } - if (val == values[i]) + if (val == get_value(i)) { if (first) { - while(i && val == values[i - 1]) + while(i && val == get_value(i - 1)) i--; } else { - while(i + 1 < size && val == values[i + 1]) + while(i + 1 < get_width() && val == get_value(i + 1)) i++; } } @@ -149,24 +185,44 @@ public: uint get_size() { return (uint) size; } + Histogram_type get_type() { return type; } + uchar *get_values() { return (uchar *) values; } void set_size (ulonglong sz) { size= (uint8) sz; } - void set_values (uchar *vals) { values= (uint8 *) vals; } + void set_type (Histogram_type t) { type= t; } + + void set_values (uchar *vals) { values= (uchar *) vals; } void set_value(uint i, double val) { - values[i]= (uint8) (val * HIST_FACTOR); + switch (type) { + case SINGLE_PREC_HB: + ((uint8 *) values)[i]= (uint8) (val * prec_factor()); + return; + case DOUBLE_PREC_HB: + ((uint16 *) values)[i]= (uint16) (val * prec_factor()); + return; + } } - void set_prev_value(uint i) { values[i]= values[i-1]; } - + void set_prev_value(uint i) + { + switch (type) { + case SINGLE_PREC_HB: + ((uint8 *) values)[i]= ((uint8 *) values)[i-1]; + return; + case DOUBLE_PREC_HB: + ((uint16 *) values)[i]= ((uint16 *) values)[i-1]; + return; + } + } double range_selectivity(double min_pos, double max_pos) { double sel; - double bucket_sel= 1.0/(size + 1); + double bucket_sel= 1.0/(get_width() + 1); uint min= find_bucket(min_pos, TRUE); uint max= find_bucket(max_pos, FALSE); sel= bucket_sel * (max - min + 1); @@ -176,14 +232,14 @@ public: double point_selectivity(double pos, double avg_sel) { double sel; - double bucket_sel= 1.0/(size + 1); + double bucket_sel= 1.0/(get_width() + 1); uint min= find_bucket(pos, TRUE); uint max= min; - while (max + 1 < size && values[max + 1] == values[max]) + while (max + 1 < get_width() && get_value(max + 1) == get_value(max)) max++; - double width= ((max + 1 == size ? 1.0 : values[max]) - - (min == 0 ? 0.0 : values[min-1])) * - INV_HIST_FACTOR; + double width= ((max + 1 == get_width() ? 1.0 : get_value(max)) - + (min == 0 ? 0.0 : get_value(min-1))) * + ((double) 1.0 / prec_factor()); sel= avg_sel * (bucket_sel * (max + 1 - min)) / width; return sel; } diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 2bf9a55f8b1..aa0c4232466 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -3777,6 +3777,17 @@ static Sys_var_ulong Sys_histogram_size( SESSION_VAR(histogram_size), CMD_LINE(REQUIRED_ARG), VALID_RANGE(0, 255), DEFAULT(0), BLOCK_SIZE(1)); +const char *histogram_types[] = + {"SINGLE_PREC_HB", "DOUBLE_PREC_HB", 0}; +static Sys_var_enum Sys_histogram_type( + "histogram_type", + "Specifies type of the histograms created by ANALYZE. " + "Possible values are: " + "SINGLE_PREC_HB - single precision height-balanced, " + "DOUBLE_PREC_HB - double precision height-balanced.", + SESSION_VAR(histogram_type), CMD_LINE(REQUIRED_ARG), + histogram_types, DEFAULT(0)); + static Sys_var_mybool Sys_no_thread_alarm( "debug_no_thread_alarm", "Disable system thread alarm calls. Disabling it may be useful " From cb47f0a79fa527bdb2fd5a0f05a9238bb2e92fe5 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sun, 31 Mar 2013 13:40:55 -0700 Subject: [PATCH 08/37] Fixed a valgrind complain on usage of an uninitialized value. --- .../suite/funcs_1/r/is_columns_mysql_embedded.result | 7 +++++++ sql/opt_range.cc | 1 + 2 files changed, 8 insertions(+) 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 fc9e68a7850..0f2635b3a42 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 @@ -13,6 +13,9 @@ def mysql column_stats avg_frequency 8 NULL YES decimal NULL NULL 12 4 NULL NULL def mysql column_stats avg_length 7 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) def mysql column_stats column_name 3 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI def mysql column_stats db_name 1 NULL NO varchar 64 192 NULL NULL NULL utf8 utf8_bin varchar(64) PRI +def mysql column_stats histogram 11 NULL YES varbinary 255 255 NULL NULL NULL NULL NULL varbinary(255) +def mysql column_stats hist_size 9 NULL YES tinyint NULL NULL 3 0 NULL NULL NULL tinyint(3) unsigned +def mysql column_stats hist_type 10 NULL YES enum 14 42 NULL NULL NULL utf8 utf8_bin enum('SINGLE_PREC_HB','DOUBLE_PREC_HB') def mysql column_stats max_value 5 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) def mysql column_stats min_value 4 NULL YES varchar 255 765 NULL NULL NULL utf8 utf8_bin varchar(255) def mysql column_stats nulls_ratio 6 NULL YES decimal NULL NULL 12 4 NULL NULL NULL decimal(12,4) @@ -256,6 +259,7 @@ ORDER BY CHARACTER_SET_NAME, COLLATION_NAME, COL_CML; COL_CML DATA_TYPE CHARACTER_SET_NAME COLLATION_NAME 1.0000 blob NULL NULL 1.0000 longblob NULL NULL +1.0000 varbinary NULL NULL 1.0000 char latin1 latin1_bin 1.0000 char latin1 latin1_swedish_ci 1.0000 varchar latin1 latin1_swedish_ci @@ -328,6 +332,9 @@ NULL mysql columns_priv Timestamp timestamp NULL NULL NULL NULL timestamp NULL mysql column_stats nulls_ratio decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_length decimal NULL NULL NULL NULL decimal(12,4) NULL mysql column_stats avg_frequency decimal NULL NULL NULL NULL decimal(12,4) +NULL mysql column_stats hist_size tinyint NULL NULL NULL NULL tinyint(3) unsigned +3.0000 mysql column_stats hist_type enum 14 42 utf8 utf8_bin enum('SINGLE_PREC_HB','DOUBLE_PREC_HB') +1.0000 mysql column_stats histogram varbinary 255 255 NULL NULL varbinary(255) 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) diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 33431df47be..fee401d7aac 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3256,6 +3256,7 @@ bool create_key_parts_for_pseudo_indexes(RANGE_OPT_PARAM *param, key_part->store_length= store_length; key_part->field= field; key_part->image_type= Field::itRAW; + key_part->flag= 0; param->key[keys]= key_part; keys++; key_part++; From e37053049341e425e139dd5bb723f1d99f56a2ad Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sun, 31 Mar 2013 23:41:47 -0700 Subject: [PATCH 09/37] Take into account the number of null values in any used column when calculating selectivity of conditions. --- mysql-test/r/selectivity.result | 31 ++++++++++++++++-- mysql-test/r/selectivity_innodb.result | 31 ++++++++++++++++-- mysql-test/t/selectivity.test | 32 ++++++++++++++++--- sql/sql_statistics.cc | 44 ++++++++++++++++++-------- 4 files changed, 114 insertions(+), 24 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 6dd0f03eb05..57b6cc9e20a 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -6,12 +6,37 @@ select @@session.use_stat_tables; COMPLEMENTARY 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_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; set @save_histogram_type=@@histogram_type; +set optimizer_use_condition_selectivity=3; +create table t1 (a int); +insert into t1 values +(9), (3), (2), (NULL), (NULL), (2), (NULL), (1), (5), (NULL); +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +select * from mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 1 9 0.4000 4.0000 1.2000 0 NULL NULL +flush table t1; +explain extended +select * from t1 where a is null; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 10 40.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where isnull(`test`.`t1`.`a`) +explain extended +select * from t1 where a is not null; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 10 60.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` is not null) +drop table t1; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; === Q15 === create view revenue0 (supplier_no, total_revenue) as select l_suppkey, sum(l_extendedprice * (1 - l_discount)) diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index fb10fb684fc..f2e0301ac8b 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -9,12 +9,37 @@ select @@session.use_stat_tables; COMPLEMENTARY 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_use_condition_selectivity=@@optimizer_use_condition_selectivity; set @save_histogram_size=@@histogram_size; set @save_histogram_type=@@histogram_type; +set optimizer_use_condition_selectivity=3; +create table t1 (a int); +insert into t1 values +(9), (3), (2), (NULL), (NULL), (2), (NULL), (1), (5), (NULL); +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +select * from mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_length avg_frequency hist_size hist_type histogram +test t1 a 1 9 0.4000 4.0000 1.2000 0 NULL NULL +flush table t1; +explain extended +select * from t1 where a is null; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 10 40.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where isnull(`test`.`t1`.`a`) +explain extended +select * from t1 where a is not null; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 10 60.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` is not null) +drop table t1; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP DATABASE IF EXISTS dbt3_s001; +CREATE DATABASE dbt3_s001; +use dbt3_s001; === Q15 === create view revenue0 (supplier_no, total_revenue) as select l_suppkey, sum(l_extendedprice * (1 - l_discount)) diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 9dda4af61eb..abc720791e8 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -7,6 +7,34 @@ set @save_use_stat_tables=@@use_stat_tables; set use_stat_tables='preferably'; +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_histogram_size=@@histogram_size; +set @save_histogram_type=@@histogram_type; + +# check that statistics on nulls is used + +set optimizer_use_condition_selectivity=3; + +create table t1 (a int); +insert into t1 values + (9), (3), (2), (NULL), (NULL), (2), (NULL), (1), (5), (NULL); + +analyze table t1; + +select * from mysql.column_stats; + +flush table t1; + +explain extended +select * from t1 where a is null; + +explain extended +select * from t1 where a is not null; + +drop table t1; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + --disable_warnings DROP DATABASE IF EXISTS dbt3_s001; --enable_warnings @@ -15,10 +43,6 @@ CREATE DATABASE dbt3_s001; use dbt3_s001; -set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; -set @save_histogram_size=@@histogram_size; -set @save_histogram_type=@@histogram_type; - --disable_query_log --disable_result_log --disable_warnings diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 74ed90cf7a1..736fb3e1f91 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3342,25 +3342,41 @@ double get_column_range_cardinality(Field *field, double res; TABLE *table= field->table; Column_statistics *col_stats= table->field[field->field_index]->read_stats; + double tab_records= table->stat_records(); if (!col_stats) - res= table->stat_records(); + return tab_records; + + double col_nulls= tab_records * col_stats->get_nulls_ratio(); + + double col_non_nulls= tab_records - col_nulls; + + if (col_non_nulls < 1) + res= 0; else if (min_endp && max_endp && min_endp->length == max_endp->length && !memcmp(min_endp->key, max_endp->key, min_endp->length)) { - double avg_frequency= col_stats->get_avg_frequency(); - res= avg_frequency; - if (avg_frequency > 1.0 + 0.000001 && - col_stats->min_value && col_stats->max_value) + if (field->null_ptr && min_endp->key[0]) { - Histogram *hist= &col_stats->histogram; - if (hist->get_size() > 0) + /* This is null single point range */ + res= col_nulls; + } + else + { + double avg_frequency= col_stats->get_avg_frequency(); + res= avg_frequency; + if (avg_frequency > 1.0 + 0.000001 && + col_stats->min_value && col_stats->max_value) { - double pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); - res= table->stat_records() * - hist->point_selectivity(pos, - avg_frequency / table->stat_records()); + Histogram *hist= &col_stats->histogram; + if (hist->get_size() > 0) + { + double pos= field->middle_point_pos(col_stats->min_value, + col_stats->max_value); + res= col_non_nulls * + hist->point_selectivity(pos, + avg_frequency / col_non_nulls); + } } } } @@ -3394,10 +3410,10 @@ double get_column_range_cardinality(Field *field, sel= (max_mp_pos - min_mp_pos); else sel= hist->range_selectivity(min_mp_pos, max_mp_pos); - res= table->stat_records() * sel; + res= col_non_nulls * sel; } else - res= table->stat_records(); + res= col_non_nulls; } return res; } From c9208300b46d7bed95a2be4f19ee51b60fb2c6ba Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 1 Apr 2013 11:17:18 -0700 Subject: [PATCH 10/37] Fixed a valgrind complain on usage of an uninitialized value. It popped up because the latest fix to handle properly null ranges was not complete. --- sql/sql_statistics.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 736fb3e1f91..6c33b88d9ad 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3386,7 +3386,7 @@ double get_column_range_cardinality(Field *field, { double sel, min_mp_pos, max_mp_pos; - if (min_endp) + if (min_endp && !min_endp->key[0]) { store_key_image_to_rec(field, (uchar *) min_endp->key, min_endp->length); From 70badba5e0e6a983a4a09617ecde5da8d459c280 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 1 Apr 2013 20:49:20 -0700 Subject: [PATCH 11/37] Fixed bug mdev-4348. The bug was caused a wrong casting. --- mysql-test/r/selectivity.result | 28 +++++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 28 +++++++++++++++++++++++ mysql-test/t/selectivity.test | 31 ++++++++++++++++++++++++++ sql/sql_select.cc | 2 +- 4 files changed, 88 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 57b6cc9e20a..b1328fddb3a 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -647,4 +647,32 @@ DROP DATABASE dbt3_s001; set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +use test; +# +# Bug mdev-4348: using view with use_condition_selectivity > 1 +# +set @tmp_use_stat_tables=@@use_stat_tables; +set use_stat_tables='never'; +set optimizer_use_condition_selectivity=3; +CREATE TABLE t1 (a int, b int); +INSERT t1 VALUES (7,1), (0,7); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT * FROM t1; +CREATE TABLE t2 (c int, d int, index idx(d)); +INSERT INTO t2 VALUES +(0,4), (8,6), (1,3), (8,5), (9,3), (2,2), (6,2), +(1,9), (6,3), (2,8), (4,1), (0,7), (4,8), (4,5); +EXPLAIN EXTENDED +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where +1 SIMPLE t2 ref idx idx 5 test.t1.b 2 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t1` join `test`.`t2` where ((`test`.`t2`.`c` = `test`.`t1`.`a`) and (`test`.`t2`.`d` = `test`.`t1`.`b`)) +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); +a b c d +0 7 0 7 +DROP VIEW v1; +DROP TABLE t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +set use_stat_tables=@tmp_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index f2e0301ac8b..8a620de68e8 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -653,6 +653,34 @@ DROP DATABASE dbt3_s001; set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +use test; +# +# Bug mdev-4348: using view with use_condition_selectivity > 1 +# +set @tmp_use_stat_tables=@@use_stat_tables; +set use_stat_tables='never'; +set optimizer_use_condition_selectivity=3; +CREATE TABLE t1 (a int, b int); +INSERT t1 VALUES (7,1), (0,7); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT * FROM t1; +CREATE TABLE t2 (c int, d int, index idx(d)); +INSERT INTO t2 VALUES +(0,4), (8,6), (1,3), (8,5), (9,3), (2,2), (6,2), +(1,9), (6,3), (2,8), (4,1), (0,7), (4,8), (4,5); +EXPLAIN EXTENDED +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where +1 SIMPLE t2 ref idx idx 5 test.t1.b 1 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t1` join `test`.`t2` where ((`test`.`t2`.`c` = `test`.`t1`.`a`) and (`test`.`t2`.`d` = `test`.`t1`.`b`)) +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); +a b c d +0 7 0 7 +DROP VIEW v1; +DROP TABLE t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +set use_stat_tables=@tmp_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index abc720791e8..88bc0683f33 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -237,4 +237,35 @@ set histogram_type=@save_histogram_type; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +use test; + +--echo # +--echo # Bug mdev-4348: using view with use_condition_selectivity > 1 +--echo # + +set @tmp_use_stat_tables=@@use_stat_tables; +set use_stat_tables='never'; +set optimizer_use_condition_selectivity=3; + +CREATE TABLE t1 (a int, b int); +INSERT t1 VALUES (7,1), (0,7); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT * FROM t1; + +CREATE TABLE t2 (c int, d int, index idx(d)); +INSERT INTO t2 VALUES + (0,4), (8,6), (1,3), (8,5), (9,3), (2,2), (6,2), + (1,9), (6,3), (2,8), (4,1), (0,7), (4,8), (4,5); + +EXPLAIN EXTENDED +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); + +SELECT * FROM v1 INNER JOIN t2 ON ( a = c AND b = d ); + +DROP VIEW v1; +DROP TABLE t1,t2; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +set use_stat_tables=@tmp_use_stat_tables; + + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index f4b808835af..f943b9b20d6 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -6962,7 +6962,7 @@ double table_multi_eq_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, Item *ref_item= keyuse->val; if (ref_item->real_item()->type() == Item::FIELD_ITEM) { - Item_field *field_item= (Item_field *) ref_item; + Item_field *field_item= (Item_field *) (ref_item->real_item()); if (item_equal->contains(field_item->field)) adjust_sel= FALSE; } From 915a8ae42c640b259f7f155e9e8497ec7947d876 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 3 Apr 2013 00:54:24 -0700 Subject: [PATCH 12/37] Fixed bug mdev-4349. Range analysis of the condition for a non-indexed column may return an impossible range. This must be taken into account. --- mysql-test/r/selectivity.result | 40 ++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 41 ++++++++++++++++++ mysql-test/t/selectivity.test | 35 ++++++++++++++++ sql/opt_range.cc | 19 ++++++++- sql/sql_select.cc | 57 +++++++++++++++++--------- 5 files changed, 171 insertions(+), 21 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index b1328fddb3a..28a38c11b01 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -675,4 +675,44 @@ DROP VIEW v1; DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@tmp_use_stat_tables; +# +# Bug mdev-4349: impossible range for non-indexed column +# +set optimizer_use_condition_selectivity=3; +create table t1 (a int); +insert into t1 values +(3), (7), (2), (5), (7), (1), (2), (2); +set optimizer_use_condition_selectivity=1; +explain extended +select * from t1 where a < 1 and a > 7; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a` < 1) and (`test`.`t1`.`a` > 7)) +select * from t1 where a < 1 and a > 7; +a +set optimizer_use_condition_selectivity=3; +explain extended +select * from t1 where a < 1 and a > 7; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where 0 +select * from t1 where a < 1 and a > 7; +a +drop table t1; +create table t1 (a int); +insert into t1 values (1); +create table t2 (b int); +insert into t2 values (2),(3); +explain extended +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select 1 AS `a` from (`test`.`t2`) where 0 +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); +a +drop table t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 8a620de68e8..02f58dbfebe 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -681,6 +681,47 @@ DROP VIEW v1; DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@tmp_use_stat_tables; +# +# Bug mdev-4349: impossible range for non-indexed column +# +set optimizer_use_condition_selectivity=3; +create table t1 (a int); +insert into t1 values +(3), (7), (2), (5), (7), (1), (2), (2); +set optimizer_use_condition_selectivity=1; +explain extended +select * from t1 where a < 1 and a > 7; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a` < 1) and (`test`.`t1`.`a` > 7)) +select * from t1 where a < 1 and a > 7; +a +set optimizer_use_condition_selectivity=3; +explain extended +select * from t1 where a < 1 and a > 7; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where 0 +select * from t1 where a < 1 and a > 7; +a +drop table t1; +create table t1 (a int); +insert into t1 values (1); +create table t2 (b int); +insert into t2 values (2),(3); +explain extended +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 1 0.00 Using where +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 0 Using where; FirstMatch(t1); Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` semi join (`test`.`t2`) where ((`test`.`t2`.`b` = `test`.`t1`.`a`) and (`test`.`t1`.`a` > 3)) +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); +a +drop table t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 88bc0683f33..15cb886dc8b 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -267,5 +267,40 @@ DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@tmp_use_stat_tables; +--echo # +--echo # Bug mdev-4349: impossible range for non-indexed column +--echo # + +set optimizer_use_condition_selectivity=3; + +create table t1 (a int); +insert into t1 values + (3), (7), (2), (5), (7), (1), (2), (2); + +set optimizer_use_condition_selectivity=1; +explain extended +select * from t1 where a < 1 and a > 7; +select * from t1 where a < 1 and a > 7; + +set optimizer_use_condition_selectivity=3; +explain extended +select * from t1 where a < 1 and a > 7; +select * from t1 where a < 1 and a > 7; + +drop table t1; + +create table t1 (a int); +insert into t1 values (1); + +create table t2 (b int); +insert into t2 values (2),(3); + +explain extended +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); +select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); + +drop table t1,t2; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index fee401d7aac..44c5f619f37 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3325,7 +3325,8 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) table->cond_selectivity= 1.0; - if (!bitmap_is_clear_all(used_fields)) + if (thd->variables.optimizer_use_condition_selectivity > 2 && + !bitmap_is_clear_all(used_fields)) { PARAM param; MEM_ROOT alloc; @@ -3362,9 +3363,25 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) double rows; if (*key) { +#if 0 rows= records_in_column_ranges(¶m, idx, *key); if (rows != HA_POS_ERROR) (*key)->field->cond_selectivity= rows/table_records; +#else + table->reginfo.impossible_range= 0; + if ((*key)->type == SEL_ARG::IMPOSSIBLE) + { + rows= 0; + table->reginfo.impossible_range= 1; + goto free_alloc; + } + else + { + rows= records_in_column_ranges(¶m, idx, *key); + if (rows != HA_POS_ERROR) + (*key)->field->cond_selectivity= rows/table_records; + } +#endif } } diff --git a/sql/sql_select.cc b/sql/sql_select.cc index f943b9b20d6..c5671544972 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3794,6 +3794,8 @@ make_join_statistics(JOIN *join, List &tables_list, all select distinct fields participate in one index. */ add_group_and_distinct_keys(join, s); + + table->cond_selectivity= 1.0; /* Perform range analysis if there are keys it could use (1). @@ -3802,7 +3804,8 @@ make_join_statistics(JOIN *join, List &tables_list, Don't do range analysis for materialized subqueries (4). Don't do range analysis for materialized derived tables (5) */ - if (!s->const_keys.is_clear_all() && // (1) + if ((!s->const_keys.is_clear_all() || + !bitmap_is_clear_all(&s->table->cond_set)) && // (1) (!s->table->pos_in_table_list->embedding || // (2) (s->table->pos_in_table_list->embedding && // (3) s->table->pos_in_table_list->embedding->sj_on_expr)) && // (3) @@ -3810,20 +3813,37 @@ make_join_statistics(JOIN *join, List &tables_list, !(s->table->pos_in_table_list->derived && // (5) s->table->pos_in_table_list->is_materialized_derived())) // (5) { - ha_rows records; - SQL_SELECT *select; - select= make_select(s->table, found_const_table_map, - found_const_table_map, - *s->on_expr_ref ? *s->on_expr_ref : conds, - 1, &error); - if (!select) - goto error; - records= get_quick_record_count(join->thd, select, s->table, - &s->const_keys, join->row_limit); - s->quick=select->quick; - s->needed_reg=select->needed_reg; - select->quick=0; - if (records == 0 && s->table->reginfo.impossible_range) + bool impossible_range= FALSE; + ha_rows records= HA_POS_ERROR; + SQL_SELECT *select= 0; + if (!s->const_keys.is_clear_all()) + { + select= make_select(s->table, found_const_table_map, + found_const_table_map, + *s->on_expr_ref ? *s->on_expr_ref : conds, + 1, &error); + if (!select) + goto error; + records= get_quick_record_count(join->thd, select, s->table, + &s->const_keys, join->row_limit); + s->quick=select->quick; + s->needed_reg=select->needed_reg; + select->quick=0; + impossible_range= records == 0 && s->table->reginfo.impossible_range; + } + if (!impossible_range) + { + if (join->thd->variables.optimizer_use_condition_selectivity > 1) + calculate_cond_selectivity_for_table(join->thd, s->table, + *s->on_expr_ref ? + *s->on_expr_ref : conds); + if (s->table->reginfo.impossible_range) + { + impossible_range= TRUE; + records= 0; + } + } + if (impossible_range) { /* Impossible WHERE or ON expression @@ -3848,13 +3868,10 @@ make_join_statistics(JOIN *join, List &tables_list, s->found_records=records; s->read_time= s->quick ? s->quick->read_time : 0.0; } - delete select; + if (select) + delete select; } - if (join->thd->variables.optimizer_use_condition_selectivity > 1) - calculate_cond_selectivity_for_table(join->thd, s->table, - *s->on_expr_ref ? - *s->on_expr_ref : conds); } if (pull_out_semijoin_tables(join)) From d62ee4e970d36649d1a9248401122eb3a63fd011 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 3 Apr 2013 20:00:10 -0700 Subject: [PATCH 13/37] Fixed bug mdev-4350. Wrong formulas used by the function Histogram::point_selectivity() could result in a negative value of selectivity returned by the function. --- mysql-test/r/selectivity.result | 45 +++++++++++++++++++++++--- mysql-test/r/selectivity_innodb.result | 45 +++++++++++++++++++++++--- mysql-test/t/selectivity.test | 37 +++++++++++++++++++-- sql/sql_statistics.h | 14 ++++---- 4 files changed, 123 insertions(+), 18 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 28a38c11b01..22efaa480c6 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -481,7 +481,7 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY -set histogram_size=15; +set histogram_size=127; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status Table is already up to date @@ -508,7 +508,7 @@ limit 10; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 -1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: @@ -536,7 +536,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=30; +set histogram_size=254; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status Table is already up to date @@ -562,7 +562,7 @@ limit 10; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 -1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: @@ -616,7 +616,7 @@ limit 10; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 -1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: @@ -715,4 +715,39 @@ select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); a drop table t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4350: erroneous negative selectivity +# +create table t1 (a int); +insert into t1 values (1), (1); +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 values (0); +select count(*) from t1; +count(*) +1025 +set use_stat_tables='preferably'; +set histogram_size=127; +set histogram_type='SINGLE_PREC_HB'; +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +flush table t1; +set optimizer_use_condition_selectivity=4; +explain extended select * from t1 where a=0; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 1025 49.61 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` = 0) +drop table t1; +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 02f58dbfebe..10e7b6a03c2 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -484,7 +484,7 @@ order by s_name limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY -set histogram_size=15; +set histogram_size=127; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status OK @@ -512,7 +512,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 -2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: @@ -540,7 +540,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=30; +set histogram_size=254; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status OK @@ -567,7 +567,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 -2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: @@ -622,7 +622,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 -2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 6.25 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.03 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: @@ -722,6 +722,41 @@ select * from t1 where a in ( select b from t2 ) AND ( a > 3 ); a drop table t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4350: erroneous negative selectivity +# +create table t1 (a int); +insert into t1 values (1), (1); +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 values (0); +select count(*) from t1; +count(*) +1025 +set use_stat_tables='preferably'; +set histogram_size=127; +set histogram_type='SINGLE_PREC_HB'; +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +flush table t1; +set optimizer_use_condition_selectivity=4; +explain extended select * from t1 where a=0; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 1025 49.61 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` = 0) +drop table t1; +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 15cb886dc8b..31ca9eefdbf 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -200,7 +200,7 @@ set optimizer_use_condition_selectivity=3; eval EXPLAIN EXTENDED $Q20; eval $Q20; -set histogram_size=15; +set histogram_size=127; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); @@ -211,7 +211,7 @@ eval EXPLAIN EXTENDED $Q20; eval $Q20; set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=30; +set histogram_size=254; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); @@ -303,4 +303,37 @@ drop table t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +--echo # +--echo # Bug mdev-4350: erroneous negative selectivity +--echo # + +create table t1 (a int); +insert into t1 values (1), (1); +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 select * from t1; +insert into t1 values (0); +select count(*) from t1; + +set use_stat_tables='preferably'; +set histogram_size=127; +set histogram_type='SINGLE_PREC_HB'; +analyze table t1; +flush table t1; + +set optimizer_use_condition_selectivity=4; +explain extended select * from t1 where a=0; + +drop table t1; + +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index b699ec7100a..e005ff86291 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -152,10 +152,10 @@ private: uint val= (uint) (pos * prec_factor()); int lp= 0; int rp= get_width() - 1; - uint i= 0; - for (int d= get_width() / 2 ; d; d= (rp - lp) / 2) + int d= get_width() / 2; + uint i= lp + d; + for ( ; d; d= (rp - lp) / 2, i= lp + d) { - i= lp + d; if (val == get_value(i)) break; if (val < get_value(i)) @@ -237,9 +237,11 @@ public: uint max= min; while (max + 1 < get_width() && get_value(max + 1) == get_value(max)) max++; - double width= ((max + 1 == get_width() ? 1.0 : get_value(max)) - - (min == 0 ? 0.0 : get_value(min-1))) * - ((double) 1.0 / prec_factor()); + double inv_prec_factor= (double) 1.0 / prec_factor(); + double width= (max + 1 == get_width() ? + 1.0 : get_value(max) * inv_prec_factor) - + (min == 0 ? + 0.0 : get_value(min-1) * inv_prec_factor); sel= avg_sel * (bucket_sel * (max + 1 - min)) / width; return sel; } From 50d4d1ca188bea01d6f5196006c5bd89c0ae9a45 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Wed, 3 Apr 2013 23:50:14 -0700 Subject: [PATCH 14/37] Fixed bug mdev-4367. When calculating selectivity of conditions one should take into account the cases when some tables to be joined are empty. --- mysql-test/r/selectivity.result | 14 ++++++++++++++ mysql-test/r/selectivity_innodb.result | 14 ++++++++++++++ mysql-test/t/selectivity.test | 22 ++++++++++++++++++++++ sql/opt_range.cc | 12 ++++++------ sql/sql_select.cc | 2 +- 5 files changed, 57 insertions(+), 7 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 22efaa480c6..bd29affc724 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -750,4 +750,18 @@ drop table t1; set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4367: join of a merged empty derived table +# when optimizer_use_condition_selectivity=3 +# +SET optimizer_use_condition_selectivity=3; +CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; +INSERT INTO t1 VALUES ('j'),('k'); +CREATE TABLE t2 (b varchar(1)) ENGINE=MyISAM; +INSERT INTO t2 VALUES ('x'),('y'); +CREATE TABLE t3 (c varchar(1), KEY(c)) ENGINE=MyISAM; +SELECT * FROM t1 STRAIGHT_JOIN (t2 JOIN t3 ON c = b AND b > 'z'); +a b c +DROP TABLE t1,t2,t3; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 10e7b6a03c2..736ee98e41a 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -757,6 +757,20 @@ drop table t1; set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4367: join of a merged empty derived table +# when optimizer_use_condition_selectivity=3 +# +SET optimizer_use_condition_selectivity=3; +CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; +INSERT INTO t1 VALUES ('j'),('k'); +CREATE TABLE t2 (b varchar(1)) ENGINE=MyISAM; +INSERT INTO t2 VALUES ('x'),('y'); +CREATE TABLE t3 (c varchar(1), KEY(c)) ENGINE=MyISAM; +SELECT * FROM t1 STRAIGHT_JOIN (t2 JOIN t3 ON c = b AND b > 'z'); +a b c +DROP TABLE t1,t2,t3; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 31ca9eefdbf..0614920dc13 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -336,4 +336,26 @@ set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +--echo # +--echo # Bug mdev-4367: join of a merged empty derived table +--echo # when optimizer_use_condition_selectivity=3 +--echo # + +SET optimizer_use_condition_selectivity=3; + +CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; +INSERT INTO t1 VALUES ('j'),('k'); + +CREATE TABLE t2 (b varchar(1)) ENGINE=MyISAM; +INSERT INTO t2 VALUES ('x'),('y'); + +CREATE TABLE t3 (c varchar(1), KEY(c)) ENGINE=MyISAM; + +SELECT * FROM t1 STRAIGHT_JOIN (t2 JOIN t3 ON c = b AND b > 'z'); + +DROP TABLE t1,t2,t3; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 44c5f619f37..3c65d99038a 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3324,6 +3324,12 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) DBUG_ENTER("calculate_cond_selectivity_for_table"); table->cond_selectivity= 1.0; + +#if 0 +#else + if (table_records == 0) + DBUG_RETURN(FALSE); +#endif if (thd->variables.optimizer_use_condition_selectivity > 2 && !bitmap_is_clear_all(used_fields)) @@ -3363,11 +3369,6 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) double rows; if (*key) { -#if 0 - rows= records_in_column_ranges(¶m, idx, *key); - if (rows != HA_POS_ERROR) - (*key)->field->cond_selectivity= rows/table_records; -#else table->reginfo.impossible_range= 0; if ((*key)->type == SEL_ARG::IMPOSSIBLE) { @@ -3381,7 +3382,6 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) if (rows != HA_POS_ERROR) (*key)->field->cond_selectivity= rows/table_records; } -#endif } } diff --git a/sql/sql_select.cc b/sql/sql_select.cc index c5671544972..109c7f22edc 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3795,7 +3795,7 @@ make_join_statistics(JOIN *join, List &tables_list, */ add_group_and_distinct_keys(join, s); - table->cond_selectivity= 1.0; + s->table->cond_selectivity= 1.0; /* Perform range analysis if there are keys it could use (1). From 4079a5dc3f98a2c7c53567106b362fc04538c7b6 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Thu, 4 Apr 2013 14:11:31 -0700 Subject: [PATCH 15/37] Fixed bug mdev-4366. When performing the range analysis for a conjunction the function calculate_cond_selectivity_for_table should take in to account that the analysis of some conjuncts may return SEL_ARG::IMPOSSIBLE. --- mysql-test/r/selectivity.result | 34 ++++++++++++++++++++++++-- mysql-test/r/selectivity_innodb.result | 34 ++++++++++++++++++++++++-- mysql-test/t/selectivity.test | 31 +++++++++++++++++++++-- sql/opt_range.cc | 14 +++++++---- 4 files changed, 102 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index bd29affc724..760c7796302 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -751,10 +751,10 @@ set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; # -# Bug mdev-4367: join of a merged empty derived table +# Bug mdev-4367: 2-way join with an empty table # when optimizer_use_condition_selectivity=3 # -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; INSERT INTO t1 VALUES ('j'),('k'); CREATE TABLE t2 (b varchar(1)) ENGINE=MyISAM; @@ -764,4 +764,34 @@ SELECT * FROM t1 STRAIGHT_JOIN (t2 JOIN t3 ON c = b AND b > 'z'); a b c DROP TABLE t1,t2,t3; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4366: impossible condition on an indexed column discovered after +# substitution of constant tables +# with optimizer_use_condition_selectivity=3 +# +CREATE TABLE t1 (pk int PRIMARY KEY, a int); +INSERT INTO t1 VALUES +(1,4), (2,6), (3,3), (4,5); +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (1), (7); +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select 1 AS `1` from `test`.`t1` join `test`.`t2` where 0 +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +1 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select 1 AS `1` from `test`.`t1` join `test`.`t2` where 0 +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +1 +DROP TABLE t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 736ee98e41a..cc9b5475ac1 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -758,10 +758,10 @@ set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; # -# Bug mdev-4367: join of a merged empty derived table +# Bug mdev-4367: 2-way join with an empty table # when optimizer_use_condition_selectivity=3 # -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; INSERT INTO t1 VALUES ('j'),('k'); CREATE TABLE t2 (b varchar(1)) ENGINE=MyISAM; @@ -771,6 +771,36 @@ SELECT * FROM t1 STRAIGHT_JOIN (t2 JOIN t3 ON c = b AND b > 'z'); a b c DROP TABLE t1,t2,t3; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4366: impossible condition on an indexed column discovered after +# substitution of constant tables +# with optimizer_use_condition_selectivity=3 +# +CREATE TABLE t1 (pk int PRIMARY KEY, a int); +INSERT INTO t1 VALUES +(1,4), (2,6), (3,3), (4,5); +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (1), (7); +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select 1 AS `1` from `test`.`t1` join `test`.`t2` where 0 +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +1 +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select 1 AS `1` from `test`.`t1` join `test`.`t2` where 0 +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +1 +DROP TABLE t1,t2; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 0614920dc13..4d0ec2d9128 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -337,11 +337,11 @@ set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; --echo # ---echo # Bug mdev-4367: join of a merged empty derived table +--echo # Bug mdev-4367: 2-way join with an empty table --echo # when optimizer_use_condition_selectivity=3 --echo # -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; CREATE TABLE t1 (a varchar(1)) ENGINE=MyISAM; INSERT INTO t1 VALUES ('j'),('k'); @@ -357,5 +357,32 @@ DROP TABLE t1,t2,t3; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +--echo # +--echo # Bug mdev-4366: impossible condition on an indexed column discovered after +--echo # substitution of constant tables +--echo # with optimizer_use_condition_selectivity=3 +--echo # + +CREATE TABLE t1 (pk int PRIMARY KEY, a int); +INSERT INTO t1 VALUES + (1,4), (2,6), (3,3), (4,5); + +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (1), (7); + +set optimizer_use_condition_selectivity=1; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; + +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; +SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; + +DROP TABLE t1,t2; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 3c65d99038a..215c85cbdf5 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3325,11 +3325,8 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) table->cond_selectivity= 1.0; -#if 0 -#else if (table_records == 0) DBUG_RETURN(FALSE); -#endif if (thd->variables.optimizer_use_condition_selectivity > 2 && !bitmap_is_clear_all(used_fields)) @@ -3338,6 +3335,7 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) MEM_ROOT alloc; SEL_TREE *tree; SEL_ARG **key, **end; + double rows; uint idx= 0; init_sql_alloc(&alloc, thd->variables.range_alloc_block_size, 0, @@ -3364,12 +3362,18 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) if (!tree) goto free_alloc; + table->reginfo.impossible_range= 0; + if (tree->type == SEL_TREE::IMPOSSIBLE) + { + rows= 0; + table->reginfo.impossible_range= 1; + goto free_alloc; + } + for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) { - double rows; if (*key) { - table->reginfo.impossible_range= 0; if ((*key)->type == SEL_ARG::IMPOSSIBLE) { rows= 0; From daaa5834c9fb567924c21d467983c1ec3401f832 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 5 Apr 2013 11:24:28 -0700 Subject: [PATCH 16/37] Fixed bug mdev-4370. Don't try to a histogram if it is not read into the cache for statistical data. It may happen so if optimizer_use_condition_selectivity is set to 3. This setting orders the optimizer not use histograms to calculate selectivity. --- mysql-test/r/selectivity.result | 28 ++++++++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 28 ++++++++++++++++++++++++++ mysql-test/t/selectivity.test | 27 +++++++++++++++++++++++++ sql/sql_statistics.cc | 4 ++-- sql/sql_statistics.h | 2 ++ 5 files changed, 87 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 760c7796302..ed8e7f8bd36 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -794,4 +794,32 @@ SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; 1 DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4370: Histograms have bean created, but the query is run after +# FLUSH TABLES with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +set histogram_size=10; +set histogram_type='SINGLE_PREC_HB'; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES (9), (1); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a > 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 75.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` > 3) +SELECT * FROM t1 WHERE a > 3; +a +9 +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index cc9b5475ac1..256b93d8cb5 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -801,6 +801,34 @@ SELECT 1 FROM t1, t2 WHERE pk = 6 AND a = 2 AND b = 10; 1 DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +# +# Bug mdev-4370: Histograms have bean created, but the query is run after +# FLUSH TABLES with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +set histogram_size=10; +set histogram_type='SINGLE_PREC_HB'; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES (9), (1); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a > 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 75.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` > 3) +SELECT * FROM t1 WHERE a > 3; +a +9 +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 4d0ec2d9128..aab8c504f3c 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -384,5 +384,32 @@ DROP TABLE t1,t2; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +--echo # +--echo # Bug mdev-4370: Histograms have bean created, but the query is run after +--echo # FLUSH TABLES with optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables=PREFERABLY; +set histogram_size=10; +set histogram_type='SINGLE_PREC_HB'; + +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES (9), (1); +ANALYZE TABLE t1; +FLUSH TABLES; + +set optimizer_use_condition_selectivity=3; + +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a > 3; +SELECT * FROM t1 WHERE a > 3; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1; + +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 6c33b88d9ad..b556c37c3fb 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3369,7 +3369,7 @@ double get_column_range_cardinality(Field *field, col_stats->min_value && col_stats->max_value) { Histogram *hist= &col_stats->histogram; - if (hist->get_size() > 0) + if (hist->is_available()) { double pos= field->middle_point_pos(col_stats->min_value, col_stats->max_value); @@ -3406,7 +3406,7 @@ double get_column_range_cardinality(Field *field, max_mp_pos= 1.0; Histogram *hist= &col_stats->histogram; - if (hist->get_size() == 0) + if (!hist->is_available()) sel= (max_mp_pos - min_mp_pos); else sel= hist->range_selectivity(min_mp_pos, max_mp_pos); diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index e005ff86291..14ffe3351d0 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -195,6 +195,8 @@ public: void set_values (uchar *vals) { values= (uchar *) vals; } + bool is_available() { return get_size() > 0 && get_values(); } + void set_value(uint i, double val) { switch (type) { From 503731d80f732a3a790443cc530fea2c3721b869 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 5 Apr 2013 13:01:46 -0700 Subject: [PATCH 17/37] Fixed bug mdev-4371. Avoid possible division by 0. --- mysql-test/r/selectivity.result | 28 ++++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 29 ++++++++++++++++++++++ mysql-test/t/selectivity.test | 33 ++++++++++++++++++++++++++ sql/sql_select.cc | 2 +- 4 files changed, 91 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index ed8e7f8bd36..5de454ba58c 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -822,4 +822,32 @@ DROP TABLE t1; set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4371: Join with condition supported by index on an empty table +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a int, b int, INDEX(a)); +CREATE TABLE t2 (c int); +INSERT INTO t2 VALUES (1),(2),(3),(4),(5),(6),(7),(8); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status Table is already up to date +test.t2 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE a > 9; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +Warnings: +Note 1003 select NULL AS `a`,NULL AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t1` join `test`.`t2` where 0 +SELECT * FROM t1, t2 WHERE a > 9; +a b c +set optimizer_switch=@save_optimizer_switch; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 256b93d8cb5..6d0c8434051 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -829,6 +829,35 @@ DROP TABLE t1; set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4371: Join with condition supported by index on an empty table +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a int, b int, INDEX(a)); +CREATE TABLE t2 (c int); +INSERT INTO t2 VALUES (1),(2),(3),(4),(5),(6),(7),(8); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE a > 9; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 1 0.00 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 8 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t1` join `test`.`t2` where (`test`.`t1`.`a` > 9) +SELECT * FROM t1, t2 WHERE a > 9; +a b c +set optimizer_switch=@save_optimizer_switch; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index aab8c504f3c..5bce7f50e0d 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -412,4 +412,37 @@ set histogram_size=@save_histogram_size; set histogram_type=@save_histogram_type; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4371: Join with condition supported by index on an empty table +--echo # with optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables=PREFERABLY; + +CREATE TABLE t1 (a int, b int, INDEX(a)); + +CREATE TABLE t2 (c int); +INSERT INTO t2 VALUES (1),(2),(3),(4),(5),(6),(7),(8); + +ANALYZE TABLE t1, t2; +FLUSH TABLES; + +set optimizer_use_condition_selectivity=3; + +set @save_optimizer_switch=@@optimizer_switch; +set optimizer_switch='index_condition_pushdown=off'; + +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE a > 9; +SELECT * FROM t1, t2 WHERE a > 9; + +set optimizer_switch=@save_optimizer_switch; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1,t2; + +set use_stat_tables=@save_use_stat_tables; + + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 109c7f22edc..368844c2379 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -7030,7 +7030,7 @@ double table_cond_selectivity(JOIN *join, uint idx, JOIN_TAB *s, /* Discount the selectivity of the access method used to join table s */ if (s->quick && s->quick->index != MAX_KEY) { - if (pos->key == 0) + if (pos->key == 0 && table_records > 0) { sel*= table->quick_rows[s->quick->index]/table_records; } From 1ae352afbe40a71f26cec2da0f08eefdef05f41f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 5 Apr 2013 23:48:49 -0700 Subject: [PATCH 18/37] Fixed bugs mdev-4357 and mdev-4359. The values of the column HIST_TYPE from the statistical table mysql.column_stats were stored in the table and read from the table incorrectly. --- mysql-test/r/selectivity.result | 6 +- mysql-test/r/selectivity_innodb.result | 6 +- mysql-test/r/statistics.result | 76 ++++++++++++++++++++------ mysql-test/t/selectivity.test | 2 +- mysql-test/t/statistics.test | 53 +++++++++++++++++- sql/sql_statistics.cc | 6 +- 6 files changed, 121 insertions(+), 28 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 5de454ba58c..f05b26cc724 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -536,7 +536,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=254; +set histogram_size=126; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status Table is already up to date @@ -562,7 +562,7 @@ limit 10; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 -1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.03 Using where +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.81 Using where 1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: @@ -616,7 +616,7 @@ limit 10; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 -1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.03 Using where +1 PRIMARY part ALL PRIMARY NULL NULL NULL 200 7.81 Using where 1 PRIMARY partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey i_ps_partkey 4 dbt3_s001.part.p_partkey 3 100.00 Using where; FirstMatch(supplier) 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 15.14 Using where Warnings: diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 6d0c8434051..57037574e5d 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -540,7 +540,7 @@ limit 10; s_name s_address Supplier#000000010 Saygah3gYWMp72i PY set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=254; +set histogram_size=126; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); Table Op Msg_type Msg_text dbt3_s001.part analyze status OK @@ -567,7 +567,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 -2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.03 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.81 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: @@ -622,7 +622,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY nation ALL PRIMARY NULL NULL NULL 25 4.00 Using where; Using temporary; Using filesort 1 PRIMARY supplier ref PRIMARY,i_s_nationkey i_s_nationkey 5 dbt3_s001.nation.n_nationkey 1 100.00 1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 -2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.03 Using where +2 MATERIALIZED part ALL PRIMARY NULL NULL NULL 200 7.81 Using where 2 MATERIALIZED partsupp ref PRIMARY,i_ps_partkey,i_ps_suppkey PRIMARY 4 dbt3_s001.part.p_partkey 3 100.00 Using where 4 DEPENDENT SUBQUERY lineitem ref i_l_shipdate,i_l_suppkey_partkey,i_l_partkey,i_l_suppkey i_l_suppkey_partkey 10 dbt3_s001.partsupp.ps_partkey,dbt3_s001.partsupp.ps_suppkey 8 14.37 Using where Warnings: diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 2289bda7889..9291b945193 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -214,15 +214,15 @@ test.t1 analyze status Table is already up to date SELECT db_name, table_name, column_name, min_value, max_value, nulls_ratio, avg_frequency, -hist_size, HEX(histogram) +hist_size, hist_type, HEX(histogram) FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size HEX(histogram) -test t1 a 0 49 0.0000 1.0000 4 2E62A1D0 -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 4 003FBFFF -test t1 c aaaa dddddddd 0.1250 7.0000 4 0055AAFF -test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 4 009393FF -test t1 e 0.01 0.112 0.2250 6.2000 4 000564E1 -test t1 f 1 5 0.2000 6.4000 4 3F7FBFBF +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size hist_type HEX(histogram) +test t1 a 0 49 0.0000 1.0000 4 SINGLE_PREC_HB 2E62A1D0 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 4 SINGLE_PREC_HB 003FBFFF +test t1 c aaaa dddddddd 0.1250 7.0000 4 SINGLE_PREC_HB 0055AAFF +test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 4 SINGLE_PREC_HB 009393FF +test t1 e 0.01 0.112 0.2250 6.2000 4 SINGLE_PREC_HB 000564E1 +test t1 f 1 5 0.2000 6.4000 4 SINGLE_PREC_HB 3F7FBFBF DELETE FROM mysql.column_stats; set histogram_size=8; set histogram_type='DOUBLE_PREC_HB'; @@ -232,15 +232,15 @@ test.t1 analyze status Table is already up to date SELECT db_name, table_name, column_name, min_value, max_value, nulls_ratio, avg_frequency, -hist_size, HEX(histogram) +hist_size, hist_type, HEX(histogram) FROM mysql.column_stats; -db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size HEX(histogram) -test t1 a 0 49 0.0000 1.0000 8 052F4363F4A1F9D0 -test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 8 0000FF3FFFBFFFFF -test t1 c aaaa dddddddd 0.1250 7.0000 8 00005555AAAAFFFF -test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 8 000026942694FFFF -test t1 e 0.01 0.112 0.2250 6.2000 8 000005056464E1E1 -test t1 f 1 5 0.2000 6.4000 8 FF3FFF7FFFBFFFBF +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size hist_type HEX(histogram) +test t1 a 0 49 0.0000 1.0000 8 DOUBLE_PREC_HB 052F4363F4A1F9D0 +test t1 b vvvvvvvvvvvvv zzzzzzzzzzzzzzzzzz 0.2000 6.4000 8 DOUBLE_PREC_HB 0000FF3FFFBFFFFF +test t1 c aaaa dddddddd 0.1250 7.0000 8 DOUBLE_PREC_HB 00005555AAAAFFFF +test t1 d 1989-03-12 1999-07-23 0.1500 8.5000 8 DOUBLE_PREC_HB 000026942694FFFF +test t1 e 0.01 0.112 0.2250 6.2000 8 DOUBLE_PREC_HB 000005056464E1E1 +test t1 f 1 5 0.2000 6.4000 8 DOUBLE_PREC_HB FF3FFF7FFFBFFFBF DELETE FROM mysql.column_stats; set histogram_size= 0; set histogram_type=default; @@ -1467,4 +1467,48 @@ UPPER(db_name) UPPER(table_name) index_name prefix_arity avg_frequency DELETE FROM mysql.table_stats; DELETE FROM mysql.column_stats; DELETE FROM mysql.index_stats; +# +# Bug mdev-4357: empty string as a value of the HIST_SIZE column +# from mysql.column_stats +# +create table t1 (a int); +insert into t1 values (1),(2),(3); +set histogram_size=10; +analyze table t1 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status OK +select db_name, table_name, column_name, +min_value, max_value, +nulls_ratio, avg_frequency, +hist_size, hist_type, HEX(histogram) +FROM mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size hist_type HEX(histogram) +test t1 a 1 3 0.0000 1.0000 10 SINGLE_PREC_HB 0000007F7F7F7FFFFFFF +set histogram_size=default; +drop table t1; +# +# Bug mdev-4359: wrong setting of the HIST_SIZE column +# (see also mdev-4357) from mysql.column_stats +# +create table t1 ( a int); +insert into t1 values (1),(2),(3),(4),(5); +set histogram_size=10; +set histogram_type='double_prec_hb'; +show variables like 'histogram%'; +Variable_name Value +histogram_size 10 +histogram_type DOUBLE_PREC_HB +analyze table t1 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status OK +select db_name, table_name, column_name, +min_value, max_value, +nulls_ratio, avg_frequency, +hist_size, hist_type, HEX(histogram) +FROM mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size hist_type HEX(histogram) +test t1 a 1 5 0.0000 1.0000 10 DOUBLE_PREC_HB 0000FF3FFF7FFFBFFFFF +set histogram_size=default; +set histogram_type=default; +drop table t1; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 5bce7f50e0d..095c853d7de 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -211,7 +211,7 @@ eval EXPLAIN EXTENDED $Q20; eval $Q20; set histogram_type='DOUBLE_PREC_HB'; -set histogram_size=254; +set histogram_size=126; ANALYZE TABLE part PERSISTENT FOR COLUMNS(p_name) INDEXES(); diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 2488e511bab..4d11e11f033 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -174,7 +174,7 @@ ANALYZE TABLE t1; SELECT db_name, table_name, column_name, min_value, max_value, nulls_ratio, avg_frequency, - hist_size, HEX(histogram) + hist_size, hist_type, HEX(histogram) FROM mysql.column_stats; DELETE FROM mysql.column_stats; @@ -186,7 +186,7 @@ ANALYZE TABLE t1; SELECT db_name, table_name, column_name, min_value, max_value, nulls_ratio, avg_frequency, - hist_size, HEX(histogram) + hist_size, hist_type, HEX(histogram) FROM mysql.column_stats; DELETE FROM mysql.column_stats; @@ -590,6 +590,53 @@ DELETE FROM mysql.table_stats; DELETE FROM mysql.column_stats; DELETE FROM mysql.index_stats; +--echo # +--echo # Bug mdev-4357: empty string as a value of the HIST_SIZE column +--echo # from mysql.column_stats +--echo # + +create table t1 (a int); +insert into t1 values (1),(2),(3); + +set histogram_size=10; + +analyze table t1 persistent for all; + +select db_name, table_name, column_name, + min_value, max_value, + nulls_ratio, avg_frequency, + hist_size, hist_type, HEX(histogram) + FROM mysql.column_stats; + +set histogram_size=default; + +drop table t1; + +--echo # +--echo # Bug mdev-4359: wrong setting of the HIST_SIZE column +--echo # (see also mdev-4357) from mysql.column_stats +--echo # + +create table t1 ( a int); +insert into t1 values (1),(2),(3),(4),(5); + +set histogram_size=10; +set histogram_type='double_prec_hb'; + +show variables like 'histogram%'; + +analyze table t1 persistent for all; + +select db_name, table_name, column_name, + min_value, max_value, + nulls_ratio, avg_frequency, + hist_size, hist_type, HEX(histogram) + FROM mysql.column_stats; + +set histogram_size=default; +set histogram_type=default; + +drop table t1; + set use_stat_tables=@save_use_stat_tables; - \ No newline at end of file diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index b556c37c3fb..6e476b34e0d 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -929,7 +929,8 @@ public: stat_field->store(table_field->collected_stats->histogram.get_size()); break; case COLUMN_STAT_HIST_TYPE: - stat_field->store(table_field->collected_stats->histogram.get_type()); + stat_field->store(table_field->collected_stats->histogram.get_type() + + 1); break; case COLUMN_STAT_HISTOGRAM: const char * col_histogram= @@ -1011,7 +1012,8 @@ public: table_field->read_stats->histogram.set_size(stat_field->val_int()); break; case COLUMN_STAT_HIST_TYPE: - Histogram_type hist_type= (Histogram_type) (stat_field->val_int()); + Histogram_type hist_type= (Histogram_type) (stat_field->val_int() - + 1); table_field->read_stats->histogram.set_type(hist_type); break; } From b2d0a33ea04a5eb20124667ea277fe78eb981a90 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 6 Apr 2013 00:51:41 -0700 Subject: [PATCH 19/37] Fixed bug mdev-4373: Valgrind complained on usage of uninitialized memory. --- mysql-test/r/selectivity.result | 17 +++++++++++++++++ mysql-test/r/selectivity_innodb.result | 17 +++++++++++++++++ mysql-test/t/selectivity.test | 23 +++++++++++++++++++++++ sql/field.cc | 12 +++++++----- 4 files changed, 64 insertions(+), 5 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index f05b26cc724..e26d2481820 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -850,4 +850,21 @@ set optimizer_switch=@save_optimizer_switch; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4373: condition on a short varchar column +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a varchar(1)); +INSERT INTO t1 VALUES ('x'), ('y'); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +SELECT * FROM t1 WHERE a <= 'w'; +a +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 57037574e5d..5f4ddf76383 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -858,6 +858,23 @@ set optimizer_switch=@save_optimizer_switch; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4373: condition on a short varchar column +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a varchar(1)); +INSERT INTO t1 VALUES ('x'), ('y'); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +SELECT * FROM t1 WHERE a <= 'w'; +a +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 095c853d7de..ccd5b09ce68 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -444,5 +444,28 @@ DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4373: condition on a short varchar column +--echo # with optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables=PREFERABLY; + +CREATE TABLE t1 (a varchar(1)); +INSERT INTO t1 VALUES ('x'), ('y'); + +ANALYZE TABLE t1; +FLUSH TABLES; + +set optimizer_use_condition_selectivity=3; + +SELECT * FROM t1 WHERE a <= 'w'; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1; + +set use_stat_tables=@save_use_stat_tables; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/field.cc b/sql/field.cc index 51fa24fc9ad..7eba901d46b 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -6202,14 +6202,16 @@ double Field_str::middle_point_pos(Field *min, Field *max) uchar minp_prefix[sizeof(ulonglong)]; uchar maxp_prefix[sizeof(ulonglong)]; ulonglong mp, minp, maxp; + uint dsz= min(field_length, sizeof(ulonglong) * charset()->mbmaxlen); + memset(mp_prefix, 0, sizeof(ulonglong)); + memset(minp_prefix, 0, sizeof(ulonglong)); + memset(maxp_prefix, 0, sizeof(ulonglong)); my_strnxfrm(charset(), mp_prefix, sizeof(mp), - ptr + length_size(), sizeof(mp) * charset()->mbmaxlen); + ptr + length_size(), dsz); my_strnxfrm(charset(), minp_prefix, sizeof(minp), - min->ptr + length_size(), - sizeof(minp) * charset()->mbmaxlen); + min->ptr + length_size(), dsz); my_strnxfrm(charset(), maxp_prefix, sizeof(maxp), - max->ptr + length_size(), - sizeof(maxp) * charset()->mbmaxlen); + max->ptr + length_size(), dsz); mp= char_prefix_to_ulonglong(mp_prefix); minp= char_prefix_to_ulonglong(minp_prefix); maxp= char_prefix_to_ulonglong(maxp_prefix); From 1c30fb2a156b9c510e1829108bc8db71dcea3d43 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 6 Apr 2013 12:33:38 -0700 Subject: [PATCH 20/37] Fixed bug mdev-4372. Range analysis of non-indexed columns should handle properly range trees with type == SEL_TREE::MAYBE. --- mysql-test/r/selectivity.result | 28 ++++++++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 28 ++++++++++++++++++++++++++ mysql-test/t/selectivity.test | 27 +++++++++++++++++++++++++ sql/opt_range.cc | 7 ++++++- 4 files changed, 89 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index e26d2481820..781df332f77 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -867,4 +867,32 @@ a set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4372: exists subquery in WHERE +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables = PREFERABLY; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES +(1),(7),(4),(7),(0),(2),(9),(4),(0),(9),(1),(3),(8),(8); +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (4),(5),(2),(5),(1),(1),(2); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +FLUSH TABLES; +SET optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 7 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 14 100.00 Using where; Using join buffer (flat, BNL join) +2 SUBQUERY t2 ALL NULL NULL NULL NULL 7 100.00 +2 SUBQUERY t1 ALL NULL NULL NULL NULL 14 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where ((exists(select 1 from `test`.`t1` join `test`.`t2`) and (`test`.`t1`.`a` <> `test`.`t2`.`b`)) or (`test`.`t1`.`a` <= 4)) +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 5f4ddf76383..e65e61af4c1 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -875,6 +875,34 @@ a set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4372: exists subquery in WHERE +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables = PREFERABLY; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES +(1),(7),(4),(7),(0),(2),(9),(4),(0),(9),(1),(3),(8),(8); +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (4),(5),(2),(5),(1),(1),(2); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +FLUSH TABLES; +SET optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 7 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 14 100.00 Using where; Using join buffer (flat, BNL join) +2 SUBQUERY t2 ALL NULL NULL NULL NULL 7 100.00 +2 SUBQUERY t1 ALL NULL NULL NULL NULL 14 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where ((exists(select 1 from `test`.`t1` join `test`.`t2`) and (`test`.`t1`.`a` <> `test`.`t2`.`b`)) or (`test`.`t1`.`a` <= 4)) +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index ccd5b09ce68..f601d4f656a 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -467,5 +467,32 @@ DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4372: exists subquery in WHERE +--echo # with optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables = PREFERABLY; + +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES + (1),(7),(4),(7),(0),(2),(9),(4),(0),(9),(1),(3),(8),(8); +CREATE TABLE t2 (b int); +INSERT INTO t2 VALUES (4),(5),(2),(5),(1),(1),(2); + +ANALYZE TABLE t1, t2; +FLUSH TABLES; + +SET optimizer_use_condition_selectivity=3; + +EXPLAIN EXTENDED +SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1,t2; + +set use_stat_tables=@save_use_stat_tables; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 215c85cbdf5..035ea3635e2 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3368,7 +3368,12 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) rows= 0; table->reginfo.impossible_range= 1; goto free_alloc; - } + } + else if (tree->type == SEL_TREE::MAYBE) + { + rows= table_records; + goto free_alloc; + } for (key= tree->keys, end= key + param.keys; key != end; key++, idx++) { From 10f0530b22d1b06c79be9fef26febebf3b9ec4a5 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 6 Apr 2013 15:36:28 -0700 Subject: [PATCH 21/37] Fixed bug mdev-4369. The function was adjusted to be able to aggregate the counters of the merged elements. Before this change it was not possible to guarantee the correctness of the counters passed to the the call-back parameter walk_action. As a result, when some elements of a Unique object were flushed into disk the function passed to merge_walk() as the call-back parameter could return wrong counters of elements. This could lead to building wrong histograms. --- mysql-test/r/statistics.result | 39 ++++++++++++++++++++++++++++++ mysql-test/t/statistics.test | 43 ++++++++++++++++++++++++++++++++++ sql/sql_class.h | 1 + sql/sql_statistics.cc | 4 ++-- sql/uniques.cc | 40 +++++++++++++++++++++++++++---- 5 files changed, 121 insertions(+), 6 deletions(-) diff --git a/mysql-test/r/statistics.result b/mysql-test/r/statistics.result index 9291b945193..20469c01a2e 100644 --- a/mysql-test/r/statistics.result +++ b/mysql-test/r/statistics.result @@ -1511,4 +1511,43 @@ test t1 a 1 5 0.0000 1.0000 10 DOUBLE_PREC_HB 0000FF3FFF7FFFBFFFFF set histogram_size=default; set histogram_type=default; drop table t1; +# +# Bug mdev-4369: histogram for a column with many distinct values +# +CREATE TABLE t1 (id int); +CREATE TABLE t2 (id int); +INSERT INTO t1 (id) VALUES (1), (1), (1),(1); +INSERT INTO t1 (id) SELECT id FROM t1; +INSERT INTO t1 SELECT id+1 FROM t1; +INSERT INTO t1 SELECT id+2 FROM t1; +INSERT INTO t1 SELECT id+4 FROM t1; +INSERT INTO t1 SELECT id+8 FROM t1; +INSERT INTO t1 SELECT id+16 FROM t1; +INSERT INTO t1 SELECT id+32 FROM t1; +INSERT INTO t1 SELECT id+64 FROM t1; +INSERT INTO t1 SELECT id+128 FROM t1; +INSERT INTO t1 SELECT id+256 FROM t1; +INSERT INTO t1 SELECT id+512 FROM t1; +INSERT INTO t2 SELECT id FROM t1 ORDER BY id*rand(); +SELECT COUNT(*) FROM t2; +COUNT(*) +8192 +SELECT COUNT(DISTINCT id) FROM t2; +COUNT(DISTINCT id) +1024 +set @@tmp_table_size=1024*16; +set @@max_heap_table_size=1024*16; +set histogram_size=63; +analyze table t2 persistent for all; +Table Op Msg_type Msg_text +test.t2 analyze status OK +select db_name, table_name, column_name, +min_value, max_value, +nulls_ratio, avg_frequency, +hist_size, hist_type, HEX(histogram) +FROM mysql.column_stats; +db_name table_name column_name min_value max_value nulls_ratio avg_frequency hist_size hist_type HEX(histogram) +test t2 id 1 1024 0.0000 8.0000 63 SINGLE_PREC_HB 03070B0F13171B1F23272B2F33373B3F43474B4F53575B5F63676B6F73777B7F83878B8F93979B9FA3A7ABAFB3B7BBBFC3C7CBCFD3D7DBDFE3E7EBEFF3F7FB +set histogram_size=default; +drop table t1, t2; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/t/statistics.test b/mysql-test/t/statistics.test index 4d11e11f033..b2a052fd3e8 100644 --- a/mysql-test/t/statistics.test +++ b/mysql-test/t/statistics.test @@ -638,5 +638,48 @@ set histogram_type=default; drop table t1; +--echo # +--echo # Bug mdev-4369: histogram for a column with many distinct values +--echo # + + +CREATE TABLE t1 (id int); +CREATE TABLE t2 (id int); + +INSERT INTO t1 (id) VALUES (1), (1), (1),(1); +INSERT INTO t1 (id) SELECT id FROM t1; +INSERT INTO t1 SELECT id+1 FROM t1; +INSERT INTO t1 SELECT id+2 FROM t1; +INSERT INTO t1 SELECT id+4 FROM t1; +INSERT INTO t1 SELECT id+8 FROM t1; +INSERT INTO t1 SELECT id+16 FROM t1; +INSERT INTO t1 SELECT id+32 FROM t1; +INSERT INTO t1 SELECT id+64 FROM t1; +INSERT INTO t1 SELECT id+128 FROM t1; +INSERT INTO t1 SELECT id+256 FROM t1; +INSERT INTO t1 SELECT id+512 FROM t1; + +INSERT INTO t2 SELECT id FROM t1 ORDER BY id*rand(); + +SELECT COUNT(*) FROM t2; +SELECT COUNT(DISTINCT id) FROM t2; + +set @@tmp_table_size=1024*16; +set @@max_heap_table_size=1024*16; + +set histogram_size=63; + +analyze table t2 persistent for all; + +select db_name, table_name, column_name, + min_value, max_value, + nulls_ratio, avg_frequency, + hist_size, hist_type, HEX(histogram) + FROM mysql.column_stats; + +set histogram_size=default; + +drop table t1, t2; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_class.h b/sql/sql_class.h index 599f59c7c27..286fbc4f81b 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -3997,6 +3997,7 @@ class Unique :public Sql_alloc uint size; uint full_size; uint min_dupl_count; /* always 0 for unions, > 0 for intersections */ + bool with_counters; bool merge(TABLE *table, uchar *buff, bool without_last_merge); diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 6e476b34e0d..37c3a93ee08 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -1348,7 +1348,7 @@ public: tree_key_length= field->pack_length(); tree= new Unique((qsort_cmp2) simple_str_key_cmp, (void*) field, - tree_key_length, max_heap_table_size); + tree_key_length, max_heap_table_size, 1); } virtual ~Count_distinct_field() @@ -1435,7 +1435,7 @@ public: tree= new Unique((qsort_cmp2) simple_ulonglong_key_cmp, (void*) &tree_key_length, - tree_key_length, max_heap_table_size); + tree_key_length, max_heap_table_size, 1); } bool add() diff --git a/sql/uniques.cc b/sql/uniques.cc index 9fa06311ece..0c1c34d495b 100644 --- a/sql/uniques.cc +++ b/sql/uniques.cc @@ -86,6 +86,7 @@ Unique::Unique(qsort_cmp2 comp_func, void * comp_func_fixed_arg, full_size= size; if (min_dupl_count_arg) full_size+= sizeof(element_count); + with_counters= test(min_dupl_count_arg); my_b_clear(&file); init_tree(&tree, (ulong) (max_in_memory_size / 16), 0, size, comp_func, NULL, comp_func_fixed_arg, MYF(MY_THREAD_SPECIFIC)); @@ -428,6 +429,22 @@ static int buffpek_compare(void *arg, uchar *key_ptr1, uchar *key_ptr2) C_MODE_END +inline +element_count get_counter_from_merged_element(void *ptr, uint ofs) +{ + element_count cnt; + memcpy((uchar *) &cnt, (uchar *) ptr + ofs, sizeof(element_count)); + return cnt; +} + + +inline +void put_counter_into_merged_element(void *ptr, uint ofs, element_count cnt) +{ + memcpy((uchar *) ptr + ofs, (uchar *) &cnt, sizeof(element_count)); +} + + /* DESCRIPTION @@ -457,6 +474,8 @@ C_MODE_END file file with all trees dumped. Trees in the file must contain sorted unique values. Cache must be initialized in read mode. + with counters take into account counters for equal merged + elements RETURN VALUE 0 ok <> 0 error @@ -466,7 +485,7 @@ static bool merge_walk(uchar *merge_buffer, ulong merge_buffer_size, uint key_length, BUFFPEK *begin, BUFFPEK *end, tree_walk_action walk_action, void *walk_action_arg, qsort_cmp2 compare, void *compare_arg, - IO_CACHE *file) + IO_CACHE *file, bool with_counters) { BUFFPEK_COMPARE_CONTEXT compare_context = { compare, compare_arg }; QUEUE queue; @@ -485,6 +504,8 @@ static bool merge_walk(uchar *merge_buffer, ulong merge_buffer_size, uint bytes_read; /* to hold return value of read_to_buffer */ BUFFPEK *top; int res= 1; + uint cnt_ofs= key_length - (with_counters ? sizeof(element_count) : 0); + element_count cnt; /* Invariant: queue must contain top element from each tree, until a tree is not completely walked through. @@ -543,9 +564,17 @@ static bool merge_walk(uchar *merge_buffer, ulong merge_buffer_size, /* new top has been obtained; if old top is unique, apply the action */ if (compare(compare_arg, old_key, top->key)) { - if (walk_action(old_key, 1, walk_action_arg)) + cnt= with_counters ? + get_counter_from_merged_element(old_key, cnt_ofs) : 1; + if (walk_action(old_key, cnt, walk_action_arg)) goto end; } + else if (with_counters) + { + cnt= get_counter_from_merged_element(top->key, cnt_ofs); + cnt+= get_counter_from_merged_element(old_key, cnt_ofs); + put_counter_into_merged_element(top->key, cnt_ofs, cnt); + } } /* Applying walk_action to the tail of the last tree: this is safe because @@ -556,7 +585,10 @@ static bool merge_walk(uchar *merge_buffer, ulong merge_buffer_size, { do { - if (walk_action(top->key, 1, walk_action_arg)) + + cnt= with_counters ? + get_counter_from_merged_element(top->key, cnt_ofs) : 1; + if (walk_action(top->key, cnt, walk_action_arg)) goto end; top->key+= key_length; } @@ -620,7 +652,7 @@ bool Unique::walk(TABLE *table, tree_walk_action action, void *walk_action_arg) (BUFFPEK *) file_ptrs.buffer, (BUFFPEK *) file_ptrs.buffer + file_ptrs.elements, action, walk_action_arg, - tree.compare, tree.custom_arg, &file); + tree.compare, tree.custom_arg, &file, with_counters); } my_free(merge_buffer); return res; From e3bf08d4b1c8d73072227f0920b6f4e8c6441591 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 6 Apr 2013 17:18:51 -0700 Subject: [PATCH 22/37] Fixed bug mdev-4363. When calculating the selectivity of a range in the function get_column_range_cardinality a check whether NULL values are included into into the range must be done. --- mysql-test/r/selectivity.result | 42 +++++++++++++++++++++++++- mysql-test/r/selectivity_innodb.result | 42 +++++++++++++++++++++++++- mysql-test/t/selectivity.test | 34 ++++++++++++++++++++- sql/opt_range.cc | 3 +- sql/sql_statistics.cc | 10 ++++-- sql/sql_statistics.h | 3 +- 6 files changed, 127 insertions(+), 7 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 781df332f77..2ab143d6b14 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -882,7 +882,7 @@ Table Op Msg_type Msg_text test.t1 analyze status OK test.t2 analyze status OK FLUSH TABLES; -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; EXPLAIN EXTENDED SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; id select_type table type possible_keys key key_len ref rows filtered Extra @@ -895,4 +895,44 @@ Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4363: selectivity of the condition a IS NULL OR IS NOT NULL +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables = PREFERABLY; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES +(1),(7),(4),(7),(NULL),(2),(NULL),(4),(NULL),(NULL),(1),(3),(8),(8); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLE t1; +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 28.57 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where isnull(`test`.`t1`.`a`) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NOT NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 71.43 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` is not null) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a IS NOT NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t1`.`a`) or (`test`.`t1`.`a` is not null)) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 69.39 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t1`.`a`) or (`test`.`t1`.`a` < 5)) +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index e65e61af4c1..2a639e922af 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -890,7 +890,7 @@ Table Op Msg_type Msg_text test.t1 analyze status OK test.t2 analyze status OK FLUSH TABLES; -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; EXPLAIN EXTENDED SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; id select_type table type possible_keys key key_len ref rows filtered Extra @@ -903,6 +903,46 @@ Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4363: selectivity of the condition a IS NULL OR IS NOT NULL +# with optimizer_use_condition_selectivity=3 +# +set use_stat_tables = PREFERABLY; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES +(1),(7),(4),(7),(NULL),(2),(NULL),(4),(NULL),(NULL),(1),(3),(8),(8); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +FLUSH TABLE t1; +set optimizer_use_condition_selectivity=3; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 28.57 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where isnull(`test`.`t1`.`a`) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NOT NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 71.43 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (`test`.`t1`.`a` is not null) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a IS NOT NULL; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t1`.`a`) or (`test`.`t1`.`a` is not null)) +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 14 69.39 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t1`.`a`) or (`test`.`t1`.`a` < 5)) +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index f601d4f656a..d8ab19ac28a 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -483,7 +483,7 @@ INSERT INTO t2 VALUES (4),(5),(2),(5),(1),(1),(2); ANALYZE TABLE t1, t2; FLUSH TABLES; -SET optimizer_use_condition_selectivity=3; +set optimizer_use_condition_selectivity=3; EXPLAIN EXTENDED SELECT * FROM t1, t2 WHERE EXISTS ( SELECT 1 FROM t1, t2 ) AND a != b OR a <= 4; @@ -495,4 +495,36 @@ DROP TABLE t1,t2; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4363: selectivity of the condition a IS NULL OR IS NOT NULL +--echo # with optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables = PREFERABLY; + +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES + (1),(7),(4),(7),(NULL),(2),(NULL),(4),(NULL),(NULL),(1),(3),(8),(8); + +ANALYZE TABLE t1; +FLUSH TABLE t1; + +set optimizer_use_condition_selectivity=3; + +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NOT NULL; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a IS NOT NULL; +EXPLAIN EXTENDED +SELECT * FROM t1 WHERE a IS NULL OR a < 5; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1; + +set use_stat_tables=@save_use_stat_tables; + + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 035ea3635e2..d101b2fe91b 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3303,7 +3303,8 @@ double records_in_column_ranges(PARAM *param, uint idx, key_range *min_endp, *max_endp; min_endp= range.start_key.length? &range.start_key : NULL; max_endp= range.end_key.length? &range.end_key : NULL; - rows= get_column_range_cardinality(field, min_endp, max_endp); + rows= get_column_range_cardinality(field, min_endp, max_endp, + range.range_flag); if (HA_POS_ERROR == rows) { total_rows= HA_POS_ERROR; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index 37c3a93ee08..efd5af7adbf 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3339,7 +3339,8 @@ double get_column_avg_frequency(Field * field) double get_column_range_cardinality(Field *field, key_range *min_endp, - key_range *max_endp) + key_range *max_endp, + uint range_flag) { double res; TABLE *table= field->table; @@ -3353,12 +3354,15 @@ double get_column_range_cardinality(Field *field, double col_non_nulls= tab_records - col_nulls; + bool nulls_incl= field->null_ptr && min_endp && min_endp->key[0] && + !(range_flag & NEAR_MIN); + if (col_non_nulls < 1) res= 0; else if (min_endp && max_endp && min_endp->length == max_endp->length && !memcmp(min_endp->key, max_endp->key, min_endp->length)) { - if (field->null_ptr && min_endp->key[0]) + if (nulls_incl) { /* This is null single point range */ res= col_nulls; @@ -3416,6 +3420,8 @@ double get_column_range_cardinality(Field *field, } else res= col_non_nulls; + if (nulls_incl) + res+= col_nulls; } return res; } diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 14ffe3351d0..ea3dba3215a 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -105,7 +105,8 @@ double get_column_avg_frequency(Field * field); double get_column_range_cardinality(Field *field, key_range *min_endp, - key_range *max_endp); + key_range *max_endp, + uint range_flag); class Histogram { From ddb84f909c4e03762ffe26e2bde9620ffa1d13fd Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 8 Apr 2013 17:40:58 -0700 Subject: [PATCH 23/37] Fixed mdev-4378. Uninitialized field cond_selectivity of the Field objects created for the fields of a temporary table could cause an assertion abort. --- mysql-test/r/selectivity.result | 29 +++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 29 +++++++++++++++++++++ mysql-test/t/selectivity.test | 35 ++++++++++++++++++++++++++ sql/sql_select.cc | 1 + 4 files changed, 94 insertions(+) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 2ab143d6b14..fb2329abd33 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -935,4 +935,33 @@ Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4378: 2-way join with a materialized IN subquery in WHERE +# when optimizer_use_condition_selectivity=4 +# +set use_stat_tables=PREFERABLY; +set histogram_size=50; +set histogram_type=SINGLE_PREC_HB; +CREATE TABLE t1 (a INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (8),(9),(6); +CREATE TABLE t2 (b INT) ENGINE=MyISAM; +INSERT INTO t2 VALUES (8),(1),(8),(9),(24),(6),(1),(6),(2),(4); +CREATE TABLE t3 (ln VARCHAR(16)) ENGINE=MyISAM; +INSERT INTO t3 VALUES +('smith'),('black'),('white'),('jones'), +('brown'),('taylor'),('anderson'),('taylor'); +ANALYZE TABLE t1, t2, t3; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +test.t3 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=4; +SELECT * FROM t1, t2 WHERE 'garcia' IN ( SELECT MIN( ln ) FROM t3 WHERE ln = 'sun' ); +a b +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2,t3; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 2a639e922af..8123641ddea 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -943,6 +943,35 @@ Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (isnull(`test`.`t set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4378: 2-way join with a materialized IN subquery in WHERE +# when optimizer_use_condition_selectivity=4 +# +set use_stat_tables=PREFERABLY; +set histogram_size=50; +set histogram_type=SINGLE_PREC_HB; +CREATE TABLE t1 (a INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (8),(9),(6); +CREATE TABLE t2 (b INT) ENGINE=MyISAM; +INSERT INTO t2 VALUES (8),(1),(8),(9),(24),(6),(1),(6),(2),(4); +CREATE TABLE t3 (ln VARCHAR(16)) ENGINE=MyISAM; +INSERT INTO t3 VALUES +('smith'),('black'),('white'),('jones'), +('brown'),('taylor'),('anderson'),('taylor'); +ANALYZE TABLE t1, t2, t3; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +test.t3 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=4; +SELECT * FROM t1, t2 WHERE 'garcia' IN ( SELECT MIN( ln ) FROM t3 WHERE ln = 'sun' ); +a b +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2,t3; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index d8ab19ac28a..ddc74a5b34f 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -526,5 +526,40 @@ DROP TABLE t1; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4378: 2-way join with a materialized IN subquery in WHERE +--echo # when optimizer_use_condition_selectivity=4 +--echo # + +set use_stat_tables=PREFERABLY; +set histogram_size=50; +set histogram_type=SINGLE_PREC_HB; + +CREATE TABLE t1 (a INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (8),(9),(6); + +CREATE TABLE t2 (b INT) ENGINE=MyISAM; +INSERT INTO t2 VALUES (8),(1),(8),(9),(24),(6),(1),(6),(2),(4); + +CREATE TABLE t3 (ln VARCHAR(16)) ENGINE=MyISAM; +INSERT INTO t3 VALUES +('smith'),('black'),('white'),('jones'), +('brown'),('taylor'),('anderson'),('taylor'); + +ANALYZE TABLE t1, t2, t3; +FLUSH TABLES; + +set optimizer_use_condition_selectivity=4; + +SELECT * FROM t1, t2 WHERE 'garcia' IN ( SELECT MIN( ln ) FROM t3 WHERE ln = 'sun' ); + +set histogram_size=@save_histogram_size; +set histogram_type=@save_histogram_type; +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1,t2,t3; + +set use_stat_tables=@save_use_stat_tables; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 368844c2379..6ee88a72795 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -14335,6 +14335,7 @@ Field *create_tmp_field_from_field(THD *thd, Field *org_field, ((Field_double *) new_field)->not_fixed= TRUE; new_field->vcol_info= 0; new_field->stored_in_db= TRUE; + new_field->cond_selectivity= 1.0; } return new_field; } From 1db675b6e8f438a6764c8ba7ee7780cd2fa7e04f Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 8 Apr 2013 21:30:42 -0700 Subject: [PATCH 24/37] Fixed mdev-4380. Uninitialized field next_equal_field of the Field objects created for the fields of a temporary table could hang the server. --- mysql-test/r/selectivity.result | 25 +++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 25 +++++++++++++++++++++ mysql-test/t/selectivity.test | 30 ++++++++++++++++++++++++++ sql/sql_select.cc | 1 + 4 files changed, 81 insertions(+) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index fb2329abd33..902288ee220 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -964,4 +964,29 @@ set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4380: 2-way join with a materialized IN subquery in WHERE +# when optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (5),(9); +CREATE TABLE t2 (b VARCHAR(8)); +INSERT INTO t2 VALUES ('red'),('blue'); +CREATE TABLE t3 (c VARCHAR(8), d VARCHAR(8)); +INSERT INTO t3 VALUES ('white','black'),('cyan','yellow'); +ANALYZE TABLE t1, t2, t3; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +test.t3 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +SELECT * FROM t1, t2 WHERE ( 'orange', 'green' ) IN ( +SELECT MAX(c), MAX(d) FROM t3, t2 WHERE c >= d AND b = c +); +a b +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2,t3; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 8123641ddea..0f9ee9c5841 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -972,6 +972,31 @@ set histogram_type=@save_histogram_type; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4380: 2-way join with a materialized IN subquery in WHERE +# when optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (5),(9); +CREATE TABLE t2 (b VARCHAR(8)); +INSERT INTO t2 VALUES ('red'),('blue'); +CREATE TABLE t3 (c VARCHAR(8), d VARCHAR(8)); +INSERT INTO t3 VALUES ('white','black'),('cyan','yellow'); +ANALYZE TABLE t1, t2, t3; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +test.t3 analyze status OK +FLUSH TABLES; +set optimizer_use_condition_selectivity=3; +SELECT * FROM t1, t2 WHERE ( 'orange', 'green' ) IN ( +SELECT MAX(c), MAX(d) FROM t3, t2 WHERE c >= d AND b = c +); +a b +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2,t3; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index ddc74a5b34f..635d9d040a6 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -561,5 +561,35 @@ DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4380: 2-way join with a materialized IN subquery in WHERE +--echo # when optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (5),(9); + +CREATE TABLE t2 (b VARCHAR(8)); +INSERT INTO t2 VALUES ('red'),('blue'); + +CREATE TABLE t3 (c VARCHAR(8), d VARCHAR(8)); +INSERT INTO t3 VALUES ('white','black'),('cyan','yellow'); + +ANALYZE TABLE t1, t2, t3; +FLUSH TABLES; + +set optimizer_use_condition_selectivity=3; + +SELECT * FROM t1, t2 WHERE ( 'orange', 'green' ) IN ( + SELECT MAX(c), MAX(d) FROM t3, t2 WHERE c >= d AND b = c +); + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1,t2,t3; + +set use_stat_tables=@save_use_stat_tables; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 6ee88a72795..7c59e294654 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -14336,6 +14336,7 @@ Field *create_tmp_field_from_field(THD *thd, Field *org_field, new_field->vcol_info= 0; new_field->stored_in_db= TRUE; new_field->cond_selectivity= 1.0; + new_field->next_equal_field= NULL; } return new_field; } From 549ada35b0ae2f5a5728243cd6be0fe8f873c792 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 9 Apr 2013 10:26:39 -0700 Subject: [PATCH 25/37] Fixed valgrind complain on usage of uninitialized data. --- sql/field.cc | 13 ++++++------- 1 file changed, 6 insertions(+), 7 deletions(-) diff --git a/sql/field.cc b/sql/field.cc index 7eba901d46b..e543689bef9 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -6202,16 +6202,15 @@ double Field_str::middle_point_pos(Field *min, Field *max) uchar minp_prefix[sizeof(ulonglong)]; uchar maxp_prefix[sizeof(ulonglong)]; ulonglong mp, minp, maxp; - uint dsz= min(field_length, sizeof(ulonglong) * charset()->mbmaxlen); - memset(mp_prefix, 0, sizeof(ulonglong)); - memset(minp_prefix, 0, sizeof(ulonglong)); - memset(maxp_prefix, 0, sizeof(ulonglong)); my_strnxfrm(charset(), mp_prefix, sizeof(mp), - ptr + length_size(), dsz); + ptr + length_size(), + data_length()); my_strnxfrm(charset(), minp_prefix, sizeof(minp), - min->ptr + length_size(), dsz); + min->ptr + length_size(), + min->data_length()); my_strnxfrm(charset(), maxp_prefix, sizeof(maxp), - max->ptr + length_size(), dsz); + max->ptr + length_size(), + max->data_length()); mp= char_prefix_to_ulonglong(mp_prefix); minp= char_prefix_to_ulonglong(minp_prefix); maxp= char_prefix_to_ulonglong(maxp_prefix); From f3bbd40349dcb75c8a9c6fad88001463ab016211 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 12 Apr 2013 02:47:46 -0700 Subject: [PATCH 26/37] Fixed bug mdev-4389. The selectivity of a range degenerated into a point never should be set to 0. --- mysql-test/r/selectivity.result | 22 ++++++++++++++++++++ mysql-test/r/selectivity_innodb.result | 22 ++++++++++++++++++++ mysql-test/t/selectivity.test | 28 ++++++++++++++++++++++++++ sql/sql_statistics.cc | 1 + 4 files changed, 73 insertions(+) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 902288ee220..8371b0eb0b6 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -989,4 +989,26 @@ a b set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4389: join with degenerated range condition in WHERE +# when optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (f1 VARCHAR(1)); +INSERT t1 VALUES ('p'),('q'); +CREATE TABLE t2 (f2 VARCHAR(1)); +INSERT INTO t2 VALUES +('o'),('v'),('f'),('f'),('e'),('l'),('j'),('p'),('r'),('j'), +('j'),('u'),('i'),('r'),('x'),('a'),('x'),('s'); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +FLUSH TABLES; +SET optimizer_use_condition_selectivity=3; +SELECT * FROM t1, t2 AS t2a, t2 AS t2b WHERE f1 <= 'a' AND t2a.f2 = f1; +f1 f2 f2 +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 0f9ee9c5841..eba0ed2f32a 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -997,6 +997,28 @@ a b set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +# +# Bug mdev-4389: join with degenerated range condition in WHERE +# when optimizer_use_condition_selectivity=3 +# +set use_stat_tables=PREFERABLY; +CREATE TABLE t1 (f1 VARCHAR(1)); +INSERT t1 VALUES ('p'),('q'); +CREATE TABLE t2 (f2 VARCHAR(1)); +INSERT INTO t2 VALUES +('o'),('v'),('f'),('f'),('e'),('l'),('j'),('p'),('r'),('j'), +('j'),('u'),('i'),('r'),('x'),('a'),('x'),('s'); +ANALYZE TABLE t1, t2; +Table Op Msg_type Msg_text +test.t1 analyze status OK +test.t2 analyze status OK +FLUSH TABLES; +SET optimizer_use_condition_selectivity=3; +SELECT * FROM t1, t2 AS t2a, t2 AS t2b WHERE f1 <= 'a' AND t2a.f2 = f1; +f1 f2 f2 +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +DROP TABLE t1,t2; +set use_stat_tables=@save_use_stat_tables; set use_stat_tables=@save_use_stat_tables; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; SET SESSION STORAGE_ENGINE=DEFAULT; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index 635d9d040a6..56908e50c65 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -591,5 +591,33 @@ DROP TABLE t1,t2,t3; set use_stat_tables=@save_use_stat_tables; +--echo # +--echo # Bug mdev-4389: join with degenerated range condition in WHERE +--echo # when optimizer_use_condition_selectivity=3 +--echo # + +set use_stat_tables=PREFERABLY; + +CREATE TABLE t1 (f1 VARCHAR(1)); +INSERT t1 VALUES ('p'),('q'); + +CREATE TABLE t2 (f2 VARCHAR(1)); +INSERT INTO t2 VALUES + ('o'),('v'),('f'),('f'),('e'),('l'),('j'),('p'),('r'),('j'), + ('j'),('u'),('i'),('r'),('x'),('a'),('x'),('s'); + +ANALYZE TABLE t1, t2; +FLUSH TABLES; + +SET optimizer_use_condition_selectivity=3; + +SELECT * FROM t1, t2 AS t2a, t2 AS t2b WHERE f1 <= 'a' AND t2a.f2 = f1; + +set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; + +DROP TABLE t1,t2; + +set use_stat_tables=@save_use_stat_tables; + set use_stat_tables=@save_use_stat_tables; diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index efd5af7adbf..df86686f773 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -3417,6 +3417,7 @@ double get_column_range_cardinality(Field *field, else sel= hist->range_selectivity(min_mp_pos, max_mp_pos); res= col_non_nulls * sel; + set_if_bigger(res, col_stats->get_avg_frequency()); } else res= col_non_nulls; From 1fcb3336b71b80479c895125beb84bc4a829cfcf Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Sat, 13 Apr 2013 10:08:30 +0100 Subject: [PATCH 27/37] Temporarily disable show_explain.test --- mysql-test/disabled.def | 1 + 1 file changed, 1 insertion(+) diff --git a/mysql-test/disabled.def b/mysql-test/disabled.def index 3d33be79473..4133eb2a12c 100644 --- a/mysql-test/disabled.def +++ b/mysql-test/disabled.def @@ -16,3 +16,4 @@ read_many_rows_innodb : Bug#11748886 2010-11-15 mattiasj report already exist archive-big : Bug#11817185 2011-03-10 Anitha Disabled since this leads to timeout on Solaris Sparc log_tables-big : Bug#11756699 2010-11-15 mattiasj report already exists mysql_embedded : Bug#12561297 2011-05-14 Anitha Dependent on PB2 changes - eventum#41836 +show_explain : Psergey: random timeout in range-checked-for-each record query. From b53bf231cc542187f56a0ba4f2a708b993e22b50 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 13 Apr 2013 02:36:30 -0700 Subject: [PATCH 28/37] Fixed compiler complains. --- sql/sql_statistics.h | 3 +++ 1 file changed, 3 insertions(+) diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index ea3dba3215a..8c1e95df1f0 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -124,6 +124,7 @@ private: case DOUBLE_PREC_HB: return ((uint) (1 << 16) - 1); } + return 1; } public: @@ -135,6 +136,7 @@ public: case DOUBLE_PREC_HB: return size / 2; } + return 0; } private: @@ -146,6 +148,7 @@ private: case DOUBLE_PREC_HB: return (uint) (((uint16 *) values)[i]); } + return 0; } uint find_bucket(double pos, bool first) From fc17efc29714b73a7b0bf806a354fa6fb294b35b Mon Sep 17 00:00:00 2001 From: Sergei Golubchik Date: Sun, 14 Apr 2013 16:48:16 +0200 Subject: [PATCH 29/37] compiler warnings --- storage/innobase/os/os0file.c | 3 +-- storage/maria/ma_check.c | 14 ++++---------- storage/maria/ma_checkpoint.c | 4 +--- storage/maria/ma_rt_split.c | 12 ++++-------- 4 files changed, 10 insertions(+), 23 deletions(-) diff --git a/storage/innobase/os/os0file.c b/storage/innobase/os/os0file.c index 0a1d3b41d0c..0d036f6f032 100644 --- a/storage/innobase/os/os0file.c +++ b/storage/innobase/os/os0file.c @@ -1369,7 +1369,6 @@ os_file_set_nocache( #endif static int os_file_set_atomic_writes(os_file_t file, const char *name) { - static int first_time = 1; int atomic_option = 1; int ret = ioctl (file, DFS_IOCTL_ATOMIC_WRITE_SET, &atomic_option); @@ -2027,7 +2026,7 @@ os_file_set_size( "InnoDB: Error: preallocating data for" " file %s failed at\n" "InnoDB: offset 0 size %lld %lld. Operating system" - " error number %llu.\n" + " error number %d.\n" "InnoDB: Check that the disk is not full" " or a disk quota exceeded.\n" "InnoDB: Some operating system error numbers" diff --git a/storage/maria/ma_check.c b/storage/maria/ma_check.c index 1feb2ae5df2..883261d5057 100644 --- a/storage/maria/ma_check.c +++ b/storage/maria/ma_check.c @@ -1246,17 +1246,13 @@ static int check_dynamic_record(HA_CHECK *param, MARIA_HA *info, int extend, { MARIA_BLOCK_INFO block_info; MARIA_SHARE *share= info->s; - my_off_t start_recpos, start_block, pos; - uchar *to; - ulong left_length; + my_off_t UNINIT_VAR(start_recpos), start_block, pos; + uchar *UNINIT_VAR(to); + ulong UNINIT_VAR(left_length); uint b_type; char llbuff[22],llbuff2[22],llbuff3[22]; DBUG_ENTER("check_dynamic_record"); - LINT_INIT(left_length); - LINT_INIT(start_recpos); - LINT_INIT(to); - pos= 0; while (pos < share->state.state.data_file_length) { @@ -1847,10 +1843,8 @@ static int check_block_record(HA_CHECK *param, MARIA_HA *info, int extend, pos < share->state.state.data_file_length; pos+= block_size, page++) { - uint row_count, real_row_count, empty_space, page_type, bitmap_pattern; + uint UNINIT_VAR(row_count), real_row_count, empty_space, page_type, bitmap_pattern; uint bitmap_for_page; - LINT_INIT(row_count); - LINT_INIT(empty_space); if (_ma_killed_ptr(param)) { diff --git a/storage/maria/ma_checkpoint.c b/storage/maria/ma_checkpoint.c index 30124b2205d..1e8adb64981 100644 --- a/storage/maria/ma_checkpoint.c +++ b/storage/maria/ma_checkpoint.c @@ -758,13 +758,11 @@ static int collect_tables(LEX_STRING *str, LSN checkpoint_start_log_horizon) struct st_state_copy *state_copies= NULL, /**< fixed-size cache of states */ *state_copies_end, /**< cache ends here */ *state_copy; /**< iterator in cache */ - TRANSLOG_ADDRESS state_copies_horizon; /**< horizon of states' _copies_ */ + TRANSLOG_ADDRESS UNINIT_VAR(state_copies_horizon); /**< horizon of states' _copies_ */ struct st_filter_param filter_param; PAGECACHE_FLUSH_FILTER filter; DBUG_ENTER("collect_tables"); - LINT_INIT(state_copies_horizon); - /* let's make a list of distinct shares */ mysql_mutex_lock(&THR_LOCK_maria); for (nb= 0, pos= maria_open_list; pos; pos= pos->next) diff --git a/storage/maria/ma_rt_split.c b/storage/maria/ma_rt_split.c index ea90b60ce12..d14422a21d2 100644 --- a/storage/maria/ma_rt_split.c +++ b/storage/maria/ma_rt_split.c @@ -185,18 +185,14 @@ static int split_maria_rtree_node(SplitStruct *node, int n_entries, double **d_buffer, int n_dim) { SplitStruct *cur; - SplitStruct *a; - SplitStruct *b; + SplitStruct *UNINIT_VAR(a); + SplitStruct *UNINIT_VAR(b); double *g1= reserve_coords(d_buffer, n_dim); double *g2= reserve_coords(d_buffer, n_dim); - SplitStruct *next; - int next_node; + SplitStruct *UNINIT_VAR(next); + int UNINIT_VAR(next_node); int i; SplitStruct *end= node + n_entries; - LINT_INIT(a); - LINT_INIT(b); - LINT_INIT(next); - LINT_INIT(next_node); if (all_size < min_size * 2) { From b12b3cae85effe89f91e816f86bd15bc4039779b Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 15 Apr 2013 22:43:07 -0700 Subject: [PATCH 30/37] Added comments. Renamed the virtual method middle_point_pos for the class Field to pos_in_interval. --- sql/field.cc | 72 ++++++++++++++- sql/field.h | 11 +-- sql/opt_range.cc | 73 +++++++++++++++ sql/sql_select.h | 6 +- sql/sql_statistics.cc | 200 ++++++++++++++++++++++++++++++++++-------- sql/sql_statistics.h | 4 +- 6 files changed, 318 insertions(+), 48 deletions(-) diff --git a/sql/field.cc b/sql/field.cc index 103d868d834..e491afd9f25 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -1274,7 +1274,24 @@ out_of_range: } -double Field_num::middle_point_pos(Field *min, Field *max) +/** + @brief + Determine the relative position of the field value in a numeric interval + + @details + The function returns a double number between 0.0 and 1.0 as the relative + position of the value of the this field in the numeric interval of [min,max]. + If the value is not in the interval the the function returns 0.0 when + the value is less than min, and, 1.0 when the value is greater than max. + + @param min value of the left end of the interval + @param max value of the right end of the interval + + @return + relative position of the field value in the numeric interval [min,max] +*/ + +double Field_num::pos_in_interval(Field *min, Field *max) { double n, d; n= val_real() - min->val_real(); @@ -6196,7 +6213,39 @@ inline ulonglong char_prefix_to_ulonglong(uchar *src) return uint8korr(src); } -double Field_str::middle_point_pos(Field *min, Field *max) +/** + @brief + Determine the relative position of the field value in a string interval + + @details + The function returns a double number between 0.0 and 1.0 as the relative + position of the value of the this field in the string interval of [min,max]. + If the value is not in the interval the the function returns 0.0 when + the value is less than min, and, 1.0 when the value is greater than max. + + @note + To calculate the relative position of the string value v in the interval + [min, max] the function first converts the beginning of these three + strings v, min, max into the strings that are used for byte comparison. + For each string not more sizeof(ulonglong) first bytes are taken + from the result of conversion. Then these bytes are interpreted as the + big-endian representation of an ulonglong integer. The values of these + integer numbers obtained for the strings v, min, max are used to calculate + the position of v in [min,max] in the same way is it's done for numeric + fields (see Field_num::pos_in_interval). + + @todo + Improve the procedure for the case when min and max have the same + beginning + + @param min value of the left end of the interval + @param max value of the right end of the interval + + @return + relative position of the field value in the string interval [min,max] +*/ + +double Field_str::pos_in_interval(Field *min, Field *max) { uchar mp_prefix[sizeof(ulonglong)]; uchar minp_prefix[sizeof(ulonglong)]; @@ -8435,7 +8484,24 @@ my_decimal *Field_bit::val_decimal(my_decimal *deciaml_value) } -double Field_bit::middle_point_pos(Field *min, Field *max) +/** + @brief + Determine the relative position of the field value in a bit interval + + @details + The function returns a double number between 0.0 and 1.0 as the relative + position of the value of the this field in the bit interval of [min,max]. + If the value is not in the interval the the function returns 0.0 when + the value is less than min, and, 1.0 when the value is greater than max. + + @param min value of the left end of the interval + @param max value of the right end of the interval + + @return + relative position of the field value in the bit interval [min,max] +*/ + +double Field_bit::pos_in_interval(Field *min, Field *max) { double n, d; n= val_real() - min->val_real(); diff --git a/sql/field.h b/sql/field.h index 550ae9d65b9..48d873beb32 100644 --- a/sql/field.h +++ b/sql/field.h @@ -723,9 +723,10 @@ public: virtual bool hash_join_is_possible() { return TRUE; } virtual bool eq_cmp_as_binary() { return TRUE; } - virtual double middle_point_pos(Field *min, Field *max) + /* Position of the field value within the interval of [min, max] */ + virtual double pos_in_interval(Field *min, Field *max) { - return (double) 1.0; + return (double) 0.5; } friend int cre_myisam(char * name, register TABLE *form, uint options, @@ -846,7 +847,7 @@ public: bool get_int(CHARSET_INFO *cs, const char *from, uint len, longlong *rnd, ulonglong unsigned_max, longlong signed_min, longlong signed_max); - double middle_point_pos(Field *min, Field *max); + double pos_in_interval(Field *min, Field *max); }; @@ -893,7 +894,7 @@ public: uint is_equal(Create_field *new_field); bool eq_cmp_as_binary() { return test(flags & BINARY_FLAG); } virtual uint length_size() { return 0; } - double middle_point_pos(Field *min, Field *max); + double pos_in_interval(Field *min, Field *max); }; /* base class for Field_string, Field_varstring and Field_blob */ @@ -2308,7 +2309,7 @@ public: { store(*((longlong *)val), TRUE); } - double middle_point_pos(Field *min, Field *max); + double pos_in_interval(Field *min, Field *max); 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/opt_range.cc b/sql/opt_range.cc index 5cadd26da6e..c29a888ea6f 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3222,6 +3222,26 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use, * Condition selectivity module ****************************************************************************/ + +/* + Build descriptors of pseudo-indexes over columns to perform range analysis + + SYNOPSIS + create_key_parts_for_pseudo_indexes() + param IN/OUT data structure for the descriptors to be built + used_fields bitmap of columns for which the descriptors are to be built + + DESCRIPTION + For each column marked in the bitmap used_fields the function builds + a descriptor of a single-component pseudo-index over this column that + can be used for the range analysis of the predicates over this columns. + The descriptors are created in the memory of param->mem_root. + + RETURN + FALSE in the case of success + TRUE otherwise +*/ + static bool create_key_parts_for_pseudo_indexes(RANGE_OPT_PARAM *param, MY_BITMAP *used_fields) @@ -3275,6 +3295,31 @@ bool create_key_parts_for_pseudo_indexes(RANGE_OPT_PARAM *param, } +/* + Estimate the number of rows in all ranges built for a column + by the range optimizer + + SYNOPSIS + records_in_column_ranges() + param the data structure to access descriptors of pseudo indexes + built over columns used in the condition of the processed query + idx the index of the descriptor of interest in param + tree the tree representing ranges built for the interesting column + + DESCRIPTION + This function retrieves the ranges represented by the SEL_ARG 'tree' and + for each of them r it calls the function get_column_range_cardinality() + that estimates the number of expected rows in r. It is assumed that param + is the data structure containing the descriptors of pseudo-indexes that + has been built to perform range analysis of the range conditions imposed + on the columns used in the processed query, while idx is the index of the + descriptor created in 'param' exactly for the column for which 'tree' + has been built by the range optimizer. + + RETURN + the number of rows in the retrieved ranges +*/ + static double records_in_column_ranges(PARAM *param, uint idx, SEL_ARG *tree) @@ -3322,6 +3367,29 @@ double records_in_column_ranges(PARAM *param, uint idx, } +/* + Calculate the selectivity of the condition imposed on the rows of a table + + SYNOPSIS + calculate_cond_selectivity_for_table() + thd the context handle + table the table of interest + cond conditions imposed on the rows of the table + + DESCRIPTION + This function calculates the selectivity of range conditions cond imposed + on the rows of 'table' in the processed query. + The calculated selectivity is assigned to the field table->cond_selectivity. + + NOTE + Currently the selectivities of range conditions over different columns are + considered independent. + + RETURN + FALSE on success + TRUE otherwise +*/ + bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) { uint keynr; @@ -3338,6 +3406,11 @@ bool calculate_cond_selectivity_for_table(THD *thd, TABLE *table, Item *cond) if (thd->variables.optimizer_use_condition_selectivity > 2 && !bitmap_is_clear_all(used_fields)) { + /* + Calculate the selectivity of the range conditions not supported + by any index + */ + PARAM param; MEM_ROOT alloc; SEL_TREE *tree; diff --git a/sql/sql_select.h b/sql/sql_select.h index d52d312f14b..9cda68bd434 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -292,7 +292,8 @@ typedef struct st_join_table { /* psergey-todo: make the below have type double, like POSITION::records_read? */ ha_rows records_read; - double cond_selectivity; + /* The selectivity of the conditions that can be pushed to the table */ + double cond_selectivity; /* Startup cost for execution */ double startup_cost; @@ -774,7 +775,8 @@ typedef struct st_position :public Sql_alloc */ double records_read; - double cond_selectivity; + /* The selectivity of the pushed down conditions */ + double cond_selectivity; /* Cost accessing the table in course of the entire complete join execution, diff --git a/sql/sql_statistics.cc b/sql/sql_statistics.cc index df86686f773..4df4b4d257d 100644 --- a/sql/sql_statistics.cc +++ b/sql/sql_statistics.cc @@ -250,12 +250,13 @@ public: 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. + data columns min_value, max_value, nulls_ratio, avg_length, avg_frequency, + hist_size, hist_type, histogram are read into internal structures. Values + of nulls_ratio, avg_length, avg_frequency, hist_size, hist_type, histogram + 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 @@ -868,11 +869,12 @@ public: @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 + columns 'min_value', 'max_value', 'nulls_ratio', 'avg_length', + 'avg_frequency', 'hist_size', 'hist_type' and 'histogram' 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, avg_frequency, hist_size, hist_type + and histogram 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. @@ -951,14 +953,15 @@ public: @details This implementation of a purely virtual method first looks for a record - the statistical table column_stats by its primary key set the record + in the statistical table column_stats by its primary key set in 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'. + 'max_value', 'nulls_ratio', 'avg_length', 'avg_frequency', 'hist_size' and + 'hist_type" 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, avg_frequency, hist_size and + hist_type of the structure read_stat from the Field structure for the field + 'table_field'. */ void get_stat_values() @@ -1022,6 +1025,22 @@ public: } } + + /** + @brief + Read histogram from of column_stats + + @details + This method first looks for a record in the statistical table column_stats + 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 value of the column 'histogram' of the table column_stat and sets + accordingly the corresponding bit in the bitmap read_stat.column_stat_nulls. + The method assumes that the value of histogram size and the pointer to + the histogram location has been already set in the fields size and values + of read_stats->histogram. + */ + void get_histogram_value() { if (find_stat()) @@ -1238,20 +1257,24 @@ public: }; +/* + Histogram_builder is a helper class that is used to build histograms + for columns +*/ class Histogram_builder { - Field *column; - uint col_length; - ha_rows records; - Field *min_value; - Field *max_value; - Histogram *histogram; - uint hist_width; - double bucket_capacity; - uint curr_bucket; - ulonglong count; - ulonglong count_distinct; + Field *column; /* table field for which the histogram is built */ + uint col_length; /* size of this field */ + ha_rows records; /* number of records the histogram is built for */ + Field *min_value; /* pointer to the minimal value for the field */ + Field *max_value; /* pointer to the maximal value for the field */ + Histogram *histogram; /* the histogram location */ + uint hist_width; /* the number of points in the histogram */ + double bucket_capacity; /* number of rows in a bucket of the histogram */ + uint curr_bucket; /* number of the current bucket to be built */ + ulonglong count; /* number of values retrieved */ + ulonglong count_distinct; /* number of distinct values retrieved */ public: Histogram_builder(Field *col, uint col_len, ha_rows rows) @@ -1280,7 +1303,7 @@ public: { column->store_field_value((uchar *) elem, col_length); histogram->set_value(curr_bucket, - column->middle_point_pos(min_value, max_value)); + column->pos_in_interval(min_value, max_value)); curr_bucket++; while (curr_bucket != hist_width && count > bucket_capacity * (curr_bucket + 1)) @@ -1389,6 +1412,10 @@ public: return count; } + /* + @brief + Build the histogram for the elements accumulated in the container of 'tree' + */ ulonglong get_value_with_histogram(ha_rows rows) { Histogram_builder hist_builder(table_field, tree_key_length, rows); @@ -1396,11 +1423,19 @@ public: return hist_builder.get_count_distinct(); } + /* + @brief + Get the size of the histogram in bytes built for table_field + */ uint get_hist_size() { return table_field->collected_stats->histogram.get_size(); } + /* + @brief + Get the pointer to the histogram built for table_field + */ uchar *get_histogram() { return table_field->collected_stats->histogram.get_values(); @@ -1936,7 +1971,6 @@ inline bool statistics_for_command_is_needed(THD *thd) @note Currently the function always is called with the parameter is_safe set to FALSE. - */ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, @@ -2051,6 +2085,36 @@ int alloc_statistics_for_table_share(THD* thd, TABLE_SHARE *table_share, DBUG_RETURN(0); } + +/** + @brief + Allocate memory for the histogram used by a table share + + @param + thd Thread handler + @param + table_share Table share for which the memory for histogram 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 histogram built for a table in the + table's share memory with the intention to read the data there from the + system persistent statistical table mysql.column_stats, + 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 + Currently the function always is called with the parameter is_safe set + to FALSE. +*/ + static int alloc_histograms_for_table_share(THD* thd, TABLE_SHARE *table_share, bool is_safe) @@ -2781,6 +2845,38 @@ bool statistics_for_tables_is_needed(THD *thd, TABLE_LIST *tables) } +/** + @brief + Read histogram for a table from the persistent statistical tables + + @param + thd The thread handle + @param + table The table to read histograms for + @param + stat_tables The array of TABLE_LIST objects for statistical tables + + @details + For the statistical table columns_stats the function looks for the rows + from this table that contain statistical data on 'table'. If such rows + are found the histograms from them are read into the memory allocated + for histograms of 'table'. Later at the query processing these histogram + are supposed to be used by the optimizer. + 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_tables_if_needed(). + + @retval + 0 If data has been successfully read for the table + @retval + 1 Otherwise + + @note + Objects of the helper Column_stat are employed read histogram + from the statistical table column_stats now. +*/ + static int read_histograms_for_table(THD *thd, TABLE *table, TABLE_LIST *stat_tables) { @@ -3311,6 +3407,17 @@ void set_statistics_for_table(THD *thd, TABLE *table) } +/** + @brief + Get the average frequency for a column + + @param + field The column whose average frequency is required + + @retval + The required average frequency +*/ + double get_column_avg_frequency(Field * field) { double res; @@ -3337,6 +3444,27 @@ double get_column_avg_frequency(Field * field) } +/** + @brief + Estimate the number of rows in a column range using data from stat tables + + @param + field The column whose range cardinality is to be estimated + @param + min_endp The left end of the range whose cardinality is required + @param + max_endp The right end of the range whose cardinality is required + @param + range_flag The range flags + + @details + The function gets an estimate of the number of rows in a column range + using the statistical data from the table column_stats. + + @retval + The required estimate of the rows in the column range +*/ + double get_column_range_cardinality(Field *field, key_range *min_endp, key_range *max_endp, @@ -3377,8 +3505,8 @@ double get_column_range_cardinality(Field *field, Histogram *hist= &col_stats->histogram; if (hist->is_available()) { - double pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); + double pos= field->pos_in_interval(col_stats->min_value, + col_stats->max_value); res= col_non_nulls * hist->point_selectivity(pos, avg_frequency / col_non_nulls); @@ -3396,8 +3524,8 @@ double get_column_range_cardinality(Field *field, { store_key_image_to_rec(field, (uchar *) min_endp->key, min_endp->length); - min_mp_pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); + min_mp_pos= field->pos_in_interval(col_stats->min_value, + col_stats->max_value); } else min_mp_pos= 0.0; @@ -3405,8 +3533,8 @@ double get_column_range_cardinality(Field *field, { store_key_image_to_rec(field, (uchar *) max_endp->key, max_endp->length); - max_mp_pos= field->middle_point_pos(col_stats->min_value, - col_stats->max_value); + max_mp_pos= field->pos_in_interval(col_stats->min_value, + col_stats->max_value); } else max_mp_pos= 1.0; diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 8c1e95df1f0..c6a72478c34 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -271,8 +271,8 @@ public: 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 */ - ulong total_hist_size; - uchar *histograms; /* Sequence of histograms */ + ulong total_hist_size; /* Total size of all histograms */ + uchar *histograms; /* Sequence of histograms */ }; From 58a77aafab52bfc3d25bfd7680f8c27ca031e403 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 16 Apr 2013 09:42:09 +0200 Subject: [PATCH 31/37] MDEV-3882: .deb versions lower than upstream repo, causing install failure The official Debian Wheezy MySQL packages have versions like 5.5.30+dfsg-xxx. Such version is larger than 5.5.30-yyy, so apt prefers it. So use instead 5.5.30+maria-yyy, which is larger and can be pulled in automatically by apt. Also included are a couple of fixes for test failures in buildbot. --- debian/autobake-deb.sh | 4 ++-- mysql-test/mysql-test-run.pl | 3 +++ mysql-test/suite/innodb/t/innodb_bug51920.test | 2 +- mysql-test/t/myisam-metadata.test | 2 +- 4 files changed, 7 insertions(+), 4 deletions(-) diff --git a/debian/autobake-deb.sh b/debian/autobake-deb.sh index 339d27bff00..5376ed58974 100755 --- a/debian/autobake-deb.sh +++ b/debian/autobake-deb.sh @@ -21,8 +21,8 @@ source ./VERSION UPSTREAM="${MYSQL_VERSION_MAJOR}.${MYSQL_VERSION_MINOR}.${MYSQL_VERSION_PATCH}${MYSQL_VERSION_EXTRA}" RELEASE_EXTRA="" -RELEASE_NAME=mariadb -PATCHLEVEL="" +RELEASE_NAME="" +PATCHLEVEL="+maria" LOGSTRING="MariaDB build" # Look up distro-version specific stuff. diff --git a/mysql-test/mysql-test-run.pl b/mysql-test/mysql-test-run.pl index 1001769e4e2..67f3a3163d8 100755 --- a/mysql-test/mysql-test-run.pl +++ b/mysql-test/mysql-test-run.pl @@ -4772,6 +4772,9 @@ sub extract_warning_lines ($$) { qr|Warning: io_setup\(\) failed|, qr|Warning: io_setup\(\) attempt|, qr|setrlimit could not change the size of core files to 'infinity';|, + qr|feedback plugin: failed to retrieve the MAC address|, + qr|Plugin 'FEEDBACK' init function returned error|, + qr|Plugin 'FEEDBACK' registration as a INFORMATION SCHEMA failed|, ); my $matched_lines= []; diff --git a/mysql-test/suite/innodb/t/innodb_bug51920.test b/mysql-test/suite/innodb/t/innodb_bug51920.test index 0d4715712b0..c83e00db22a 100644 --- a/mysql-test/suite/innodb/t/innodb_bug51920.test +++ b/mysql-test/suite/innodb/t/innodb_bug51920.test @@ -36,7 +36,7 @@ let $wait_condition = # depending on platform. # connection con1; --- error 1317, 2006, 2013 +-- error 1317, 2006, 2013, ER_CONNECTION_KILLED reap; connection default; DROP TABLE bug51920; diff --git a/mysql-test/t/myisam-metadata.test b/mysql-test/t/myisam-metadata.test index c5327aa3a71..e80332eaa57 100644 --- a/mysql-test/t/myisam-metadata.test +++ b/mysql-test/t/myisam-metadata.test @@ -33,7 +33,7 @@ while ($1) ALTER TABLE t1 ENABLE KEYS; --connection default ---let $wait_timeout=10 +--let $wait_timeout=60 --let $show_statement= SHOW PROCESSLIST --let $field= State --let $condition= = 'Repair by sorting' From 82eedf4e9745aa570b88b225941120475f9f74c9 Mon Sep 17 00:00:00 2001 From: Lixun Peng Date: Tue, 16 Apr 2013 19:43:28 +0800 Subject: [PATCH 32/37] Makeing rpl_filter for each Master_info. Users can set different repplication filter rules for each replication connection, in my.cnf or command line. But the rules set online will not record in master.info, it means if users restart MySQL, these rules will lose. So if users wantn't their replication filter rules lose, they should write the rules in my.cnf. Users can set rules by 2 ways: 1. Online SET command, "SET connection_name.replication_filter_settings = rules;". 2. In my.cnf, "connection_name.replication_filter_settings = rules". If no connection_name in my.cnf, this rule will apply for ALL replication connection. If no connetion_name in SET statement, this rull will apply for default_connection_name. --- libmysqld/lib_sql.cc | 2 +- sql/keycaches.cc | 66 ++++++++++++++++++++++++++++++++++++++++++ sql/keycaches.h | 12 ++++++++ sql/log_event.cc | 11 +++++-- sql/mysqld.cc | 60 +++++++++++++++++++++++++------------- sql/rpl_filter.cc | 12 ++++++++ sql/rpl_filter.h | 3 +- sql/rpl_mi.cc | 68 ++++++++++++++++++++++++++++++++++++++++++++ sql/rpl_mi.h | 4 +++ sql/rpl_rli.cc | 2 +- sql/slave.cc | 6 ++-- sql/sql_acl.cc | 5 ++++ sql/sql_class.h | 4 +++ sql/sql_parse.cc | 11 +++++-- sql/sys_vars.cc | 65 +++++++++++++++++++++++++++++++++++++++--- sql/sys_vars.h | 5 ++-- 16 files changed, 300 insertions(+), 36 deletions(-) diff --git a/libmysqld/lib_sql.cc b/libmysqld/lib_sql.cc index 5e798674c2d..16c6cc94f1b 100644 --- a/libmysqld/lib_sql.cc +++ b/libmysqld/lib_sql.cc @@ -604,7 +604,7 @@ int init_embedded_server(int argc, char **argv, char **groups) // FIXME initialize binlog_filter and rpl_filter if not already done // corresponding delete is in clean_up() if(!binlog_filter) binlog_filter = new Rpl_filter; - if(!rpl_filter) rpl_filter = new Rpl_filter; + if(!global_rpl_filter) global_rpl_filter = new Rpl_filter; if (opt_init_file) { diff --git a/sql/keycaches.cc b/sql/keycaches.cc index 84ed67d00f0..9e4b943dc83 100644 --- a/sql/keycaches.cc +++ b/sql/keycaches.cc @@ -20,6 +20,7 @@ ****************************************************************************/ NAMED_ILIST key_caches; +NAMED_ILIST rpl_filters; /** ilink (intrusive list element) with a name @@ -66,6 +67,23 @@ uchar* find_named(I_List *list, const char *name, uint length, } +bool NAMED_ILIST::delete_element(const char *name, uint length, void (*free_element)(const char *name, uchar*)) +{ + I_List_iterator it(*this); + NAMED_ILINK *element; + DBUG_ENTER("NAMED_ILIST::delete_element"); + while ((element= it++)) + { + if (element->cmp(name, length)) + { + (*free_element)(element->name, element->data); + delete element; + DBUG_RETURN(0); + } + } + DBUG_RETURN(1); +} + void NAMED_ILIST::delete_elements(void (*free_element)(const char *name, uchar*)) { NAMED_ILINK *element; @@ -159,3 +177,51 @@ bool process_key_caches(process_key_cache_t func, void *param) return res != 0; } +/* Rpl_filter functions */ + +LEX_STRING default_rpl_filter_base= {C_STRING_WITH_LEN("")}; + +Rpl_filter *get_rpl_filter(LEX_STRING *filter_name) +{ + if (!filter_name->length) + filter_name= &default_rpl_filter_base; + return ((Rpl_filter*) find_named(&rpl_filters, + filter_name->str, filter_name->length, 0)); +} + +Rpl_filter *create_rpl_filter(const char *name, uint length) +{ + Rpl_filter *filter; + DBUG_ENTER("create_rpl_filter"); + DBUG_PRINT("enter",("name: %.*s", length, name)); + + filter= new Rpl_filter; + if (filter) + { + if (!new NAMED_ILINK(&rpl_filters, name, length, (uchar*) filter)) + { + delete filter; + filter= 0; + } + } + DBUG_RETURN(filter); +} + + +Rpl_filter *get_or_create_rpl_filter(const char *name, uint length) +{ + LEX_STRING rpl_filter_name; + Rpl_filter *filter; + + rpl_filter_name.str= (char *) name; + rpl_filter_name.length= length; + if (!(filter= get_rpl_filter(&rpl_filter_name))) + filter= create_rpl_filter(name, length); + return filter; +} + +void free_rpl_filter(const char *name, Rpl_filter *filter) +{ + delete filter; +} + diff --git a/sql/keycaches.h b/sql/keycaches.h index 04d3f6145e7..2d52cb28973 100644 --- a/sql/keycaches.h +++ b/sql/keycaches.h @@ -18,6 +18,7 @@ #include "sql_list.h" #include +#include extern "C" { @@ -30,8 +31,10 @@ class NAMED_ILIST: public I_List { public: void delete_elements(void (*free_element)(const char*, uchar*)); + bool delete_element(const char *name, uint length, void (*free_element)(const char*, uchar*)); }; +/* For key cache */ extern LEX_STRING default_key_cache_base; extern KEY_CACHE zero_key_cache; extern NAMED_ILIST key_caches; @@ -42,4 +45,13 @@ KEY_CACHE *get_or_create_key_cache(const char *name, uint length); void free_key_cache(const char *name, KEY_CACHE *key_cache); bool process_key_caches(process_key_cache_t func, void *param); +/* For Rpl_filter */ +extern LEX_STRING default_rpl_filter_base; +extern NAMED_ILIST rpl_filters; + +Rpl_filter *create_rpl_filter(const char *name, uint length); +Rpl_filter *get_rpl_filter(LEX_STRING *filter_name); +Rpl_filter *get_or_create_rpl_filter(const char *name, uint length); +void free_rpl_filter(const char *name, Rpl_filter *filter); + #endif /* KEYCACHES_INCLUDED */ diff --git a/sql/log_event.cc b/sql/log_event.cc index 104ea948cfc..f65d96eb9a8 100644 --- a/sql/log_event.cc +++ b/sql/log_event.cc @@ -3756,6 +3756,7 @@ int Query_log_event::do_apply_event(Relay_log_info const *rli, HA_CREATE_INFO db_options; uint64 sub_id= 0; rpl_gtid gtid; + Rpl_filter *rpl_filter= rli->mi->rpl_filter; DBUG_ENTER("Query_log_event::do_apply_event"); /* @@ -5439,6 +5440,7 @@ int Load_log_event::do_apply_event(NET* net, Relay_log_info const *rli, bool use_rli_only_for_errors) { LEX_STRING new_db; + Rpl_filter *rpl_filter= rli->mi->rpl_filter; DBUG_ENTER("Load_log_event::do_apply_event"); new_db.length= db_len; @@ -10044,8 +10046,8 @@ check_table_map(Relay_log_info const *rli, RPL_TABLE_LIST *table_list) enum_tbl_map_status res= OK_TO_PROCESS; if (rli->sql_thd->slave_thread /* filtering is for slave only */ && - (!rpl_filter->db_ok(table_list->db) || - (rpl_filter->is_on() && !rpl_filter->tables_ok("", table_list)))) + (!rli->mi->rpl_filter->db_ok(table_list->db) || + (rli->mi->rpl_filter->is_on() && !rli->mi->rpl_filter->tables_ok("", table_list)))) res= FILTERED_OUT; else { @@ -10079,6 +10081,7 @@ int Table_map_log_event::do_apply_event(Relay_log_info const *rli) char *db_mem, *tname_mem; size_t dummy_len; void *memory; + Rpl_filter *filter; DBUG_ENTER("Table_map_log_event::do_apply_event(Relay_log_info*)"); DBUG_ASSERT(rli->sql_thd == thd); @@ -10092,7 +10095,9 @@ int Table_map_log_event::do_apply_event(Relay_log_info const *rli) NullS))) DBUG_RETURN(HA_ERR_OUT_OF_MEM); - strmov(db_mem, rpl_filter->get_rewrite_db(m_dbnam, &dummy_len)); + /* call from mysql_client_binlog_statement() will not set rli->mi */ + filter= rli->sql_thd->slave_thread ? rli->mi->rpl_filter : global_rpl_filter; + strmov(db_mem, filter->get_rewrite_db(m_dbnam, &dummy_len)); strmov(tname_mem, m_tblnam); table_list->init_one_table(db_mem, strlen(db_mem), diff --git a/sql/mysqld.cc b/sql/mysqld.cc index f794dc6ffa5..2d9923d3ef0 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -621,7 +621,8 @@ MYSQL_FILE *bootstrap_file; int bootstrap_error; I_List threads; -Rpl_filter* rpl_filter; +Rpl_filter* cur_rpl_filter; +Rpl_filter* global_rpl_filter; Rpl_filter* binlog_filter; THD *first_global_thread() @@ -1882,7 +1883,7 @@ void clean_up(bool print_message) #endif my_uuid_end(); delete binlog_filter; - delete rpl_filter; + delete global_rpl_filter; end_ssl(); vio_end(); my_regex_end(); @@ -3587,9 +3588,9 @@ static int init_common_variables() max_system_variables.pseudo_thread_id= (ulong)~0; server_start_time= flush_status_time= my_time(0); - rpl_filter= new Rpl_filter; + global_rpl_filter= new Rpl_filter; binlog_filter= new Rpl_filter; - if (!rpl_filter || !binlog_filter) + if (!global_rpl_filter || !binlog_filter) { sql_perror("Could not allocate replication and binlog filters"); return 1; @@ -5125,6 +5126,9 @@ int mysqld_main(int argc, char **argv) create_shutdown_thread(); start_handle_manager(); + /* Copy default global rpl_filter to global_rpl_filter */ + copy_filter_setting(global_rpl_filter, get_or_create_rpl_filter("", 0)); + /* init_slave() must be called after the thread keys are created. Some parts of the code (e.g. SHOW STATUS LIKE 'slave_running' and other @@ -6541,28 +6545,28 @@ struct my_option my_long_options[]= "while having selected a different or no database. If you need cross " "database updates to work, make sure you have 3.23.28 or later, and use " "replicate-wild-do-table=db_name.%.", - 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"replicate-do-table", OPT_REPLICATE_DO_TABLE, "Tells the slave thread to restrict replication to the specified table. " "To specify more than one table, use the directive multiple times, once " "for each table. This will work for cross-database updates, in contrast " - "to replicate-do-db.", 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + "to replicate-do-db.", 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"replicate-ignore-db", OPT_REPLICATE_IGNORE_DB, "Tells the slave thread to not replicate to the specified database. To " "specify more than one database to ignore, use the directive multiple " "times, once for each database. This option will not work if you use " "cross database updates. If you need cross database updates to work, " "make sure you have 3.23.28 or later, and use replicate-wild-ignore-" - "table=db_name.%. ", 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + "table=db_name.%. ", 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"replicate-ignore-table", OPT_REPLICATE_IGNORE_TABLE, "Tells the slave thread to not replicate to the specified table. To specify " "more than one table to ignore, use the directive multiple times, once for " "each table. This will work for cross-database updates, in contrast to " - "replicate-ignore-db.", 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + "replicate-ignore-db.", 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"replicate-rewrite-db", OPT_REPLICATE_REWRITE_DB, "Updates to a database with a different name than the original. Example: " "replicate-rewrite-db=master_db_name->slave_db_name.", - 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, #ifdef HAVE_REPLICATION {"replicate-same-server-id", 0, "In replication, if set to 1, do not skip events having our server id. " @@ -6578,7 +6582,7 @@ struct my_option my_long_options[]= "database updates. Example: replicate-wild-do-table=foo%.bar% will " "replicate only updates to tables in all databases that start with foo " "and whose table names start with bar.", - 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"replicate-wild-ignore-table", OPT_REPLICATE_WILD_IGNORE_TABLE, "Tells the slave thread to not replicate to the tables that match the " "given wildcard pattern. To specify more than one table to ignore, use " @@ -6586,7 +6590,7 @@ struct my_option my_long_options[]= "cross-database updates. Example: replicate-wild-ignore-table=foo%.bar% " "will not do updates to tables in databases that start with foo and whose " "table names start with bar.", - 0, 0, 0, GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, + 0, 0, 0, GET_STR | GET_ASK_ADDR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0}, {"safe-mode", OPT_SAFE, "Skip some optimize stages (for testing). Deprecated.", 0, 0, 0, GET_NO_ARG, NO_ARG, 0, 0, 0, 0, 0, 0}, {"safe-user-create", 0, @@ -7752,12 +7756,12 @@ mysqld_get_one_option(int optid, #ifdef HAVE_REPLICATION case (int)OPT_REPLICATE_IGNORE_DB: { - rpl_filter->add_ignore_db(argument); + cur_rpl_filter->add_ignore_db(argument); break; } case (int)OPT_REPLICATE_DO_DB: { - rpl_filter->add_do_db(argument); + cur_rpl_filter->add_do_db(argument); break; } case (int)OPT_REPLICATE_REWRITE_DB: @@ -7788,7 +7792,7 @@ mysqld_get_one_option(int optid, return 1; } - rpl_filter->add_db_rewrite(key, val); + cur_rpl_filter->add_db_rewrite(key, val); break; } @@ -7804,7 +7808,7 @@ mysqld_get_one_option(int optid, } case (int)OPT_REPLICATE_DO_TABLE: { - if (rpl_filter->add_do_table(argument)) + if (cur_rpl_filter->add_do_table(argument)) { sql_print_error("Could not add do table rule '%s'!\n", argument); return 1; @@ -7813,7 +7817,7 @@ mysqld_get_one_option(int optid, } case (int)OPT_REPLICATE_WILD_DO_TABLE: { - if (rpl_filter->add_wild_do_table(argument)) + if (cur_rpl_filter->add_wild_do_table(argument)) { sql_print_error("Could not add do table rule '%s'!\n", argument); return 1; @@ -7822,7 +7826,7 @@ mysqld_get_one_option(int optid, } case (int)OPT_REPLICATE_WILD_IGNORE_TABLE: { - if (rpl_filter->add_wild_ignore_table(argument)) + if (cur_rpl_filter->add_wild_ignore_table(argument)) { sql_print_error("Could not add ignore table rule '%s'!\n", argument); return 1; @@ -7831,7 +7835,7 @@ mysqld_get_one_option(int optid, } case (int)OPT_REPLICATE_IGNORE_TABLE: { - if (rpl_filter->add_ignore_table(argument)) + if (cur_rpl_filter->add_ignore_table(argument)) { sql_print_error("Could not add ignore table rule '%s'!\n", argument); return 1; @@ -7952,7 +7956,7 @@ mysqld_get_one_option(int optid, C_MODE_START static void* -mysql_getopt_value(const char *keyname, uint key_length, +mysql_getopt_value(const char *name, uint length, const struct my_option *option, int *error) { if (error) @@ -7965,7 +7969,7 @@ mysql_getopt_value(const char *keyname, uint key_length, case OPT_KEY_CACHE_PARTITIONS: { KEY_CACHE *key_cache; - if (!(key_cache= get_or_create_key_cache(keyname, key_length))) + if (!(key_cache= get_or_create_key_cache(name, length))) { if (error) *error= EXIT_OUT_OF_MEMORY; @@ -7984,6 +7988,22 @@ mysql_getopt_value(const char *keyname, uint key_length, return (uchar**) &key_cache->param_partitions; } } + case OPT_REPLICATE_DO_DB: + case OPT_REPLICATE_DO_TABLE: + case OPT_REPLICATE_IGNORE_DB: + case OPT_REPLICATE_IGNORE_TABLE: + case OPT_REPLICATE_WILD_DO_TABLE: + case OPT_REPLICATE_WILD_IGNORE_TABLE: + case OPT_REPLICATE_REWRITE_DB: + { + /* Store current filter for mysqld_get_one_option() */ + if (!(cur_rpl_filter= get_or_create_rpl_filter(name, length))) + { + if (error) + *error= EXIT_OUT_OF_MEMORY; + } + return 0; + } } return option->value; } diff --git a/sql/rpl_filter.cc b/sql/rpl_filter.cc index f2bd036896d..2e7a2242d45 100644 --- a/sql/rpl_filter.cc +++ b/sql/rpl_filter.cc @@ -734,6 +734,18 @@ Rpl_filter::get_rewrite_db(const char* db, size_t *new_len) } +void +Rpl_filter::copy_rewrite_db(Rpl_filter *from) +{ + I_List_iterator it(from->rewrite_db); + i_string_pair* tmp; + DBUG_ASSERT(rewrite_db.is_empty()); + + /* TODO: Add memory checking here and in all add_xxxx functions ! */ + while ((tmp=it++)) + add_db_rewrite(tmp->key, tmp->val); +} + I_List* Rpl_filter::get_do_db() { diff --git a/sql/rpl_filter.h b/sql/rpl_filter.h index 2eb0340b714..65d11cfb6e6 100644 --- a/sql/rpl_filter.h +++ b/sql/rpl_filter.h @@ -88,6 +88,7 @@ public: bool rewrite_db_is_empty(); const char* get_rewrite_db(const char* db, size_t *new_len); + void copy_rewrite_db(Rpl_filter *from); I_List* get_do_db(); I_List* get_ignore_db(); @@ -139,7 +140,7 @@ private: I_List rewrite_db; }; -extern Rpl_filter *rpl_filter; +extern Rpl_filter *global_rpl_filter; extern Rpl_filter *binlog_filter; #endif // RPL_FILTER_H diff --git a/sql/rpl_mi.cc b/sql/rpl_mi.cc index fdff61fafec..38fcc54e891 100644 --- a/sql/rpl_mi.cc +++ b/sql/rpl_mi.cc @@ -60,6 +60,13 @@ Master_info::Master_info(LEX_STRING *connection_name_arg, connection_name.length+1); my_casedn_str(system_charset_info, cmp_connection_name.str); } + /* When MySQL restarted, all Rpl_filter settings which aren't in the my.cnf + * will lose. So if you want a setting will not lose after restarting, you + * should add them into my.cnf + * */ + rpl_filter= get_or_create_rpl_filter(connection_name.str, + connection_name.length); + copy_filter_setting(rpl_filter, global_rpl_filter); my_init_dynamic_array(&ignore_server_ids, sizeof(global_system_variables.server_id), 16, 16, @@ -78,6 +85,8 @@ Master_info::Master_info(LEX_STRING *connection_name_arg, Master_info::~Master_info() { + rpl_filters.delete_element(connection_name.str, connection_name.length, + (void (*)(const char*, uchar*)) free_rpl_filter); my_free(connection_name.str); delete_dynamic(&ignore_server_ids); mysql_mutex_destroy(&run_lock); @@ -711,6 +720,65 @@ void create_logfile_name_with_suffix(char *res_file_name, size_t length, } } +void copy_filter_setting(Rpl_filter* dst_filter, Rpl_filter* src_filter) +{ + char buf[256]; + String tmp(buf, sizeof(buf), &my_charset_bin); + + dst_filter->get_do_db(&tmp); + if (tmp.is_empty()) + { + src_filter->get_do_db(&tmp); + if (!tmp.is_empty()) + dst_filter->set_do_db(tmp.ptr()); + } + + dst_filter->get_do_table(&tmp); + if (tmp.is_empty()) + { + src_filter->get_do_table(&tmp); + if (!tmp.is_empty()) + dst_filter->set_do_table(tmp.ptr()); + } + + dst_filter->get_ignore_db(&tmp); + if (tmp.is_empty()) + { + src_filter->get_ignore_db(&tmp); + if (!tmp.is_empty()) + dst_filter->set_ignore_db(tmp.ptr()); + } + + dst_filter->get_ignore_table(&tmp); + if (tmp.is_empty()) + { + src_filter->get_ignore_table(&tmp); + if (!tmp.is_empty()) + dst_filter->set_ignore_table(tmp.ptr()); + } + + dst_filter->get_wild_do_table(&tmp); + if (tmp.is_empty()) + { + src_filter->get_wild_do_table(&tmp); + if (!tmp.is_empty()) + dst_filter->set_wild_do_table(tmp.ptr()); + } + + dst_filter->get_wild_ignore_table(&tmp); + if (tmp.is_empty()) + { + src_filter->get_wild_ignore_table(&tmp); + if (!tmp.is_empty()) + dst_filter->set_wild_ignore_table(tmp.ptr()); + } + + if (dst_filter->rewrite_db_is_empty()) + { + if (!src_filter->rewrite_db_is_empty()) + dst_filter->copy_rewrite_db(src_filter); + } +} Master_info_index::Master_info_index() { diff --git a/sql/rpl_mi.h b/sql/rpl_mi.h index b6a3e7d91b9..64501e96f00 100644 --- a/sql/rpl_mi.h +++ b/sql/rpl_mi.h @@ -21,6 +21,8 @@ #include "rpl_rli.h" #include "rpl_reporting.h" #include "my_sys.h" +#include "rpl_filter.h" +#include "keycaches.h" typedef struct st_mysql MYSQL; @@ -92,6 +94,7 @@ class Master_info : public Slave_reporting_capability uint32 file_id; /* for 3.23 load data infile */ Relay_log_info rli; uint port; + Rpl_filter* rpl_filter; /* Each replication can set its filter rule*/ /* to hold checksum alg in use until IO thread has received FD. Initialized to novalue, then set to the queried from master @@ -141,6 +144,7 @@ int flush_master_info(Master_info* mi, bool flush_relay_log_cache, bool need_lock_relay_log); int change_master_server_id_cmp(ulong *id1, ulong *id2); +void copy_filter_setting(Rpl_filter* dst_filter, Rpl_filter* src_filter); /* Multi master are handled trough this struct. diff --git a/sql/rpl_rli.cc b/sql/rpl_rli.cc index 6d53e6c3187..11c6e54c8f8 100644 --- a/sql/rpl_rli.cc +++ b/sql/rpl_rli.cc @@ -61,7 +61,7 @@ Relay_log_info::Relay_log_info(bool is_slave_recovery) gtid_sub_id(0), tables_to_lock(0), tables_to_lock_count(0), last_event_start_time(0), deferred_events(NULL),m_flags(0), row_stmt_start_timestamp(0), long_find_row_note_printed(false), - m_annotate_event(0) + m_annotate_event(0), mi(0) { DBUG_ENTER("Relay_log_info::Relay_log_info"); diff --git a/sql/slave.cc b/sql/slave.cc index 8f1d8669770..2e436d5e8b4 100644 --- a/sql/slave.cc +++ b/sql/slave.cc @@ -2302,6 +2302,7 @@ static bool send_show_master_info_data(THD *thd, Master_info *mi, bool full, DBUG_PRINT("info",("host is set: '%s'", mi->host)); String *packet= &thd->packet; Protocol *protocol= thd->protocol; + Rpl_filter *rpl_filter= mi->rpl_filter; char buf[256]; String tmp(buf, sizeof(buf), &my_charset_bin); @@ -3787,6 +3788,7 @@ pthread_handler_t handle_slave_sql(void *arg) thd = new THD; // note that contructor of THD uses DBUG_ ! thd->thread_stack = (char*)&thd; // remember where our stack is + thd->rpl_filter = mi->rpl_filter; DBUG_ASSERT(rli->inited); DBUG_ASSERT(rli->mi == mi); @@ -3817,7 +3819,7 @@ pthread_handler_t handle_slave_sql(void *arg) } thd->init_for_queries(); thd->rli_slave= rli; - if ((rli->deferred_events_collecting= rpl_filter->is_on())) + if ((rli->deferred_events_collecting= mi->rpl_filter->is_on())) { rli->deferred_events= new Deferred_log_events(rli); } @@ -4145,7 +4147,7 @@ static int process_io_create_file(Master_info* mi, Create_file_log_event* cev) if (unlikely(!cev->is_valid())) DBUG_RETURN(1); - if (!rpl_filter->db_ok(cev->db)) + if (!mi->rpl_filter->db_ok(cev->db)) { skip_load_data_infile(net); DBUG_RETURN(0); diff --git a/sql/sql_acl.cc b/sql/sql_acl.cc index d9470094c63..7810bdb16e2 100644 --- a/sql/sql_acl.cc +++ b/sql/sql_acl.cc @@ -1905,6 +1905,7 @@ bool change_password(THD *thd, const char *host, const char *user, { TABLE_LIST tables; TABLE *table; + Rpl_filter *rpl_filter= thd->rpl_filter; /* Buffer should be extended when password length is extended. */ char buff[512]; ulong query_length; @@ -3593,6 +3594,7 @@ int mysql_table_grant(THD *thd, TABLE_LIST *table_list, TABLE_LIST tables[3]; bool create_new_users=0; char *db_name, *table_name; + Rpl_filter *rpl_filter= thd->rpl_filter; DBUG_ENTER("mysql_table_grant"); if (!initialized) @@ -3869,6 +3871,7 @@ bool mysql_routine_grant(THD *thd, TABLE_LIST *table_list, bool is_proc, TABLE_LIST tables[2]; bool create_new_users=0, result=0; char *db_name, *table_name; + Rpl_filter *rpl_filter= thd->rpl_filter; DBUG_ENTER("mysql_routine_grant"); if (!initialized) @@ -4009,6 +4012,7 @@ bool mysql_grant(THD *thd, const char *db, List &list, char tmp_db[SAFE_NAME_LEN+1]; bool create_new_users=0; TABLE_LIST tables[2]; + Rpl_filter *rpl_filter= thd->rpl_filter; DBUG_ENTER("mysql_grant"); if (!initialized) @@ -5758,6 +5762,7 @@ void get_mqh(const char *user, const char *host, USER_CONN *uc) #define GRANT_TABLES 6 int open_grant_tables(THD *thd, TABLE_LIST *tables) { + Rpl_filter *rpl_filter= thd->rpl_filter; DBUG_ENTER("open_grant_tables"); if (!initialized) diff --git a/sql/sql_class.h b/sql/sql_class.h index 221c0d3bd51..8e2bd59da57 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -47,6 +47,7 @@ class Reprepare_observer; class Relay_log_info; +class Rpl_filter; class Query_log_event; class Load_log_event; @@ -1588,6 +1589,9 @@ public: /* Slave applier execution context */ Relay_log_info* rli_slave; + /* Used to SLAVE SQL thread */ + Rpl_filter* rpl_filter; + void reset_for_next_command(bool calculate_userstat); /* Constant for THD::where initialization in the beginning of every query. diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index f3cc03e9cc6..c6372099600 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -170,8 +170,8 @@ const char *xa_state_names[]={ */ inline bool all_tables_not_ok(THD *thd, TABLE_LIST *tables) { - return rpl_filter->is_on() && tables && !thd->spcont && - !rpl_filter->tables_ok(thd->db, tables); + return thd->rpl_filter->is_on() && tables && !thd->spcont && + !thd->rpl_filter->tables_ok(thd->db, tables); } #endif @@ -1954,6 +1954,8 @@ mysql_execute_command(THD *thd) #ifdef HAVE_REPLICATION /* have table map for update for multi-update statement (BUG#37051) */ bool have_table_map_for_update= FALSE; + /* */ + Rpl_filter *rpl_filter= thd->rpl_filter; #endif DBUG_ENTER("mysql_execute_command"); #ifdef WITH_PARTITION_STORAGE_ENGINE @@ -2438,6 +2440,11 @@ case SQLCOM_PREPARE: else delete mi; } + else + { + mi->rpl_filter= get_or_create_rpl_filter(lex_mi->connection_name.str, + lex_mi->connection_name.length); + } mysql_mutex_unlock(&LOCK_active_mi); break; diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 762b35da89a..4393809a6fe 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -3371,19 +3371,48 @@ static Sys_var_mybool Sys_relay_log_recovery( bool Sys_var_rpl_filter::global_update(THD *thd, set_var *var) { bool result= true; // Assume error + Master_info *mi; mysql_mutex_unlock(&LOCK_global_system_variables); mysql_mutex_lock(&LOCK_active_mi); - if (!master_info_index->give_error_if_slave_running()) - result= set_filter_value(var->save_result.string_value.str); + + if (!var->base.length) // no base name + { + mi= master_info_index-> + get_master_info(&thd->variables.default_master_connection, + MYSQL_ERROR::WARN_LEVEL_ERROR); + } + else // has base name + { + mi= master_info_index-> + get_master_info(&var->base, + MYSQL_ERROR::WARN_LEVEL_WARN); + } + + if (mi) + { + if (mi->rli.slave_running) + { + my_error(ER_SLAVE_MUST_STOP, MYF(0), + mi->connection_name.length, + mi->connection_name.str); + result= true; + } + else + { + result= set_filter_value(var->save_result.string_value.str, mi); + } + } + mysql_mutex_unlock(&LOCK_active_mi); mysql_mutex_lock(&LOCK_global_system_variables); return result; } -bool Sys_var_rpl_filter::set_filter_value(const char *value) +bool Sys_var_rpl_filter::set_filter_value(const char *value, Master_info *mi) { bool status= true; + Rpl_filter* rpl_filter= mi ? mi->rpl_filter : global_rpl_filter; switch (opt_id) { case OPT_REPLICATE_DO_DB: @@ -3413,7 +3442,32 @@ uchar *Sys_var_rpl_filter::global_value_ptr(THD *thd, LEX_STRING *base) { char buf[256]; String tmp(buf, sizeof(buf), &my_charset_bin); + uchar *ret; + Master_info *mi; + Rpl_filter *rpl_filter; + mysql_mutex_unlock(&LOCK_global_system_variables); + mysql_mutex_lock(&LOCK_active_mi); + if (!base->length) // no base name + { + mi= master_info_index-> + get_master_info(&thd->variables.default_master_connection, + MYSQL_ERROR::WARN_LEVEL_ERROR); + } + else // has base name + { + mi= master_info_index-> + get_master_info(base, + MYSQL_ERROR::WARN_LEVEL_WARN); + } + mysql_mutex_lock(&LOCK_global_system_variables); + + if (!mi) + { + mysql_mutex_unlock(&LOCK_active_mi); + return 0; + } + rpl_filter= mi->rpl_filter; tmp.length(0); switch (opt_id) { @@ -3437,7 +3491,10 @@ uchar *Sys_var_rpl_filter::global_value_ptr(THD *thd, LEX_STRING *base) break; } - return (uchar *) thd->strmake(tmp.ptr(), tmp.length()); + ret= (uchar *) thd->strmake(tmp.ptr(), tmp.length()); + mysql_mutex_unlock(&LOCK_active_mi); + + return ret; } static Sys_var_rpl_filter Sys_replicate_do_db( diff --git a/sql/sys_vars.h b/sql/sys_vars.h index b04e3817406..f8b6537453c 100644 --- a/sql/sys_vars.h +++ b/sql/sys_vars.h @@ -28,6 +28,7 @@ #include "keycaches.h" #include "strfunc.h" #include "tztime.h" // my_tz_find, my_tz_SYSTEM, struct Time_zone +#include "rpl_mi.h" // For Multi-Source Replication /* a set of mostly trivial (as in f(X)=X) defines below to make system variable @@ -562,7 +563,7 @@ public: NO_ARG, SHOW_CHAR, 0, NULL, VARIABLE_NOT_IN_BINLOG, NULL, NULL, NULL), opt_id(getopt_id) { - option.var_type= GET_STR; + option.var_type= GET_STR | GET_ASK_ADDR; } bool do_check(THD *thd, set_var *var) @@ -588,7 +589,7 @@ public: protected: uchar *global_value_ptr(THD *thd, LEX_STRING *base); - bool set_filter_value(const char *value); + bool set_filter_value(const char *value, Master_info *mi); }; /** From eb95ebf9174228376b4de272deb1c7eac947168e Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 16 Apr 2013 17:33:47 +0200 Subject: [PATCH 33/37] Fix race in test case. --- mysql-test/r/myisam-metadata.result | 3 +++ mysql-test/t/myisam-metadata.test | 5 ++++- storage/myisam/ha_myisam.cc | 2 ++ 3 files changed, 9 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/myisam-metadata.result b/mysql-test/r/myisam-metadata.result index 5192253d5d1..4d49bac9436 100644 --- a/mysql-test/r/myisam-metadata.result +++ b/mysql-test/r/myisam-metadata.result @@ -5,7 +5,10 @@ a VARCHAR(100), INDEX(a) ) ENGINE=MyISAM; ALTER TABLE t1 DISABLE KEYS; +SET debug_sync= 'myisam_after_repair_by_sort SIGNAL waiting WAIT_FOR go'; ALTER TABLE t1 ENABLE KEYS; +SET debug_sync= 'now WAIT_FOR waiting'; +SET debug_sync= 'now SIGNAL go'; SHOW TABLE STATUS LIKE 't1'; Name Engine Version Row_format Rows Avg_row_length Data_length Max_data_length Index_length Data_free Auto_increment Create_time Update_time Check_time Collation Checksum Create_options Comment t1 MyISAM 10 Dynamic 100000 27 # # # 0 NULL # # # latin1_swedish_ci NULL diff --git a/mysql-test/t/myisam-metadata.test b/mysql-test/t/myisam-metadata.test index e80332eaa57..df596b69b37 100644 --- a/mysql-test/t/myisam-metadata.test +++ b/mysql-test/t/myisam-metadata.test @@ -29,7 +29,8 @@ while ($1) --enable_query_log --connect(con1,localhost,root,,) ---send +SET debug_sync= 'myisam_after_repair_by_sort SIGNAL waiting WAIT_FOR go'; +send ALTER TABLE t1 ENABLE KEYS; --connection default @@ -38,6 +39,8 @@ while ($1) --let $field= State --let $condition= = 'Repair by sorting' --source include/wait_show_condition.inc +SET debug_sync= 'now WAIT_FOR waiting'; +SET debug_sync= 'now SIGNAL go'; --replace_column 7 # 8 # 9 # 12 # 13 # 14 # SHOW TABLE STATUS LIKE 't1'; diff --git a/storage/myisam/ha_myisam.cc b/storage/myisam/ha_myisam.cc index 770c7d660b2..e455b00418c 100644 --- a/storage/myisam/ha_myisam.cc +++ b/storage/myisam/ha_myisam.cc @@ -30,6 +30,7 @@ #include "rt_index.h" #include "sql_table.h" // tablename_to_filename #include "sql_class.h" // THD +#include "debug_sync.h" ulonglong myisam_recover_options; static ulong opt_myisam_block_size; @@ -1131,6 +1132,7 @@ int ha_myisam::repair(THD *thd, HA_CHECK ¶m, bool do_optimize) thd_proc_info(thd, "Repair by sorting"); error = mi_repair_by_sort(¶m, file, fixed_name, test(param.testflag & T_QUICK)); + DEBUG_SYNC(thd, "myisam_after_repair_by_sort"); } } else From 0508f766b44fc669fbdb353a372b56b1c8e4a588 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 16 Apr 2013 17:36:40 +0200 Subject: [PATCH 34/37] Fixes for stuff seen in buildbot: - Fix embedded build - Backport disable of fallocate, it creates too short ibdata1 when used with O_DIRECT on old kernels - Do not disable innodb during .deb install, we need it for mysql.rpl_slave_state table. --- debian/dist/Debian/mariadb-server-5.5.postinst | 2 +- debian/dist/Ubuntu/mariadb-server-5.5.postinst | 2 +- sql/sys_vars.h | 1 + storage/innobase/handler/ha_innodb.cc | 2 +- storage/xtradb/handler/ha_innodb.cc | 2 +- 5 files changed, 5 insertions(+), 4 deletions(-) diff --git a/debian/dist/Debian/mariadb-server-5.5.postinst b/debian/dist/Debian/mariadb-server-5.5.postinst index 4da8979fd03..69259c9fb04 100644 --- a/debian/dist/Debian/mariadb-server-5.5.postinst +++ b/debian/dist/Debian/mariadb-server-5.5.postinst @@ -21,7 +21,7 @@ invoke() { fi } -MYSQL_BOOTSTRAP="/usr/sbin/mysqld --bootstrap --user=mysql --skip-grant-tables --loose-innodb=OFF --default-storage-engine=myisam" +MYSQL_BOOTSTRAP="/usr/sbin/mysqld --bootstrap --user=mysql --skip-grant-tables --default-storage-engine=myisam" test_mysql_access() { mysql --no-defaults -u root -h localhost /dev/null 2>&1 diff --git a/debian/dist/Ubuntu/mariadb-server-5.5.postinst b/debian/dist/Ubuntu/mariadb-server-5.5.postinst index 1c7aa37f69f..6a4d6b5c0d9 100644 --- a/debian/dist/Ubuntu/mariadb-server-5.5.postinst +++ b/debian/dist/Ubuntu/mariadb-server-5.5.postinst @@ -21,7 +21,7 @@ invoke() { fi } -MYSQL_BOOTSTRAP="/usr/sbin/mysqld --bootstrap --user=mysql --skip-grant-tables --loose-innodb=OFF --default-storage-engine=myisam" +MYSQL_BOOTSTRAP="/usr/sbin/mysqld --bootstrap --user=mysql --skip-grant-tables --default-storage-engine=myisam" test_mysql_access() { mysql --no-defaults -u root -h localhost /dev/null 2>&1 diff --git a/sql/sys_vars.h b/sql/sys_vars.h index f8b6537453c..8a92f22f3c2 100644 --- a/sql/sys_vars.h +++ b/sql/sys_vars.h @@ -552,6 +552,7 @@ protected: } }; +class Master_info; class Sys_var_rpl_filter: public sys_var { private: diff --git a/storage/innobase/handler/ha_innodb.cc b/storage/innobase/handler/ha_innodb.cc index 328f81036c9..722e6a669fb 100644 --- a/storage/innobase/handler/ha_innodb.cc +++ b/storage/innobase/handler/ha_innodb.cc @@ -2492,7 +2492,7 @@ innobase_change_buffering_inited_ok: innobase_commit_concurrency_init_default(); #ifdef HAVE_POSIX_FALLOCATE - srv_use_posix_fallocate = (ibool) innobase_use_fallocate; + srv_use_posix_fallocate = 0 && (ibool) innobase_use_fallocate; #endif srv_use_atomic_writes = (ibool) innobase_use_atomic_writes; if (innobase_use_atomic_writes) { diff --git a/storage/xtradb/handler/ha_innodb.cc b/storage/xtradb/handler/ha_innodb.cc index a50e631de32..dacaf6fae9c 100644 --- a/storage/xtradb/handler/ha_innodb.cc +++ b/storage/xtradb/handler/ha_innodb.cc @@ -3082,7 +3082,7 @@ innobase_change_buffering_inited_ok: #endif #ifdef HAVE_POSIX_FALLOCATE - srv_use_posix_fallocate = (ibool) innobase_use_fallocate; + srv_use_posix_fallocate = 0 && (ibool) innobase_use_fallocate; #endif srv_use_atomic_writes = (ibool) innobase_use_atomic_writes; if (innobase_use_atomic_writes) { From 4656060f118caba30912cca2557d72fcea307283 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 16 Apr 2013 18:52:23 +0200 Subject: [PATCH 35/37] debug_sync is only available in debug build. --- mysql-test/t/myisam-metadata.test | 1 + 1 file changed, 1 insertion(+) diff --git a/mysql-test/t/myisam-metadata.test b/mysql-test/t/myisam-metadata.test index df596b69b37..2bbcc89a702 100644 --- a/mysql-test/t/myisam-metadata.test +++ b/mysql-test/t/myisam-metadata.test @@ -3,6 +3,7 @@ # --source include/big_test.inc +--source include/have_debug_sync.inc --disable_warnings DROP TABLE IF EXISTS t1; From 02ef7e0af0d2834a0c506ff62e896494bdd19bd9 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 17 Apr 2013 13:35:16 +0200 Subject: [PATCH 36/37] Fix that multi_source tests did not reset @@global.gtid_pos between tests. --- mysql-test/suite/multi_source/reset_master_slave.inc | 1 + mysql-test/suite/multi_source/simple.result | 12 ++++++------ 2 files changed, 7 insertions(+), 6 deletions(-) diff --git a/mysql-test/suite/multi_source/reset_master_slave.inc b/mysql-test/suite/multi_source/reset_master_slave.inc index 63ba3ee00af..2678602291f 100644 --- a/mysql-test/suite/multi_source/reset_master_slave.inc +++ b/mysql-test/suite/multi_source/reset_master_slave.inc @@ -23,6 +23,7 @@ while ($con_name != 'No such row') --error 0,ER_FLUSH_MASTER_BINLOG_CLOSED reset master; +set global gtid_pos=''; eval set default_master_connection = '$default_master'; --source include/end_include_file.inc diff --git a/mysql-test/suite/multi_source/simple.result b/mysql-test/suite/multi_source/simple.result index 39c94fda736..fa738fbf712 100644 --- a/mysql-test/suite/multi_source/simple.result +++ b/mysql-test/suite/multi_source/simple.result @@ -11,8 +11,8 @@ include/wait_for_slave_to_start.inc set default_master_connection = ''; show all slaves status; Connection_name Slave_SQL_State Slave_IO_State Master_Host Master_User Master_Port Connect_Retry Master_Log_File Read_Master_Log_Pos Relay_Log_File Relay_Log_Pos Relay_Master_Log_File Slave_IO_Running Slave_SQL_Running Replicate_Do_DB Replicate_Ignore_DB Replicate_Do_Table Replicate_Ignore_Table Replicate_Wild_Do_Table Replicate_Wild_Ignore_Table Last_Errno Last_Error Skip_Counter Exec_Master_Log_Pos Relay_Log_Space Until_Condition Until_Log_File Until_Log_Pos Master_SSL_Allowed Master_SSL_CA_File Master_SSL_CA_Path Master_SSL_Cert Master_SSL_Cipher Master_SSL_Key Seconds_Behind_Master Master_SSL_Verify_Server_Cert Last_IO_Errno Last_IO_Error Last_SQL_Errno Last_SQL_Error Replicate_Ignore_Server_Ids Master_Server_Id Using_Gtid Retried_transactions Max_relay_log_size Executed_log_entries Slave_received_heartbeats Slave_heartbeat_period Gtid_Pos -slave1 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_1 60 master-bin.000001 311 mysqld-relay-bin-slave1.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 1 0 0 1073741824 7 0 60.000 0-1-3 -slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 0-1-3 +slave1 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_1 60 master-bin.000001 311 mysqld-relay-bin-slave1.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 1 0 0 1073741824 7 0 60.000 +slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 start all slaves; stop slave 'slave1'; show slave 'slave1' status; @@ -60,18 +60,18 @@ Using_Gtid 0 reset slave 'slave1'; show all slaves status; Connection_name Slave_SQL_State Slave_IO_State Master_Host Master_User Master_Port Connect_Retry Master_Log_File Read_Master_Log_Pos Relay_Log_File Relay_Log_Pos Relay_Master_Log_File Slave_IO_Running Slave_SQL_Running Replicate_Do_DB Replicate_Ignore_DB Replicate_Do_Table Replicate_Ignore_Table Replicate_Wild_Do_Table Replicate_Wild_Ignore_Table Last_Errno Last_Error Skip_Counter Exec_Master_Log_Pos Relay_Log_Space Until_Condition Until_Log_File Until_Log_Pos Master_SSL_Allowed Master_SSL_CA_File Master_SSL_CA_Path Master_SSL_Cert Master_SSL_Cipher Master_SSL_Key Seconds_Behind_Master Master_SSL_Verify_Server_Cert Last_IO_Errno Last_IO_Error Last_SQL_Errno Last_SQL_Error Replicate_Ignore_Server_Ids Master_Server_Id Using_Gtid Retried_transactions Max_relay_log_size Executed_log_entries Slave_received_heartbeats Slave_heartbeat_period Gtid_Pos -slave1 127.0.0.1 root MYPORT_1 60 4 599 No No 0 0 0 904 None 0 No NULL No 0 0 1 0 0 1073741824 7 0 60.000 0-1-3 -slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 0-1-3 +slave1 127.0.0.1 root MYPORT_1 60 4 599 No No 0 0 0 904 None 0 No NULL No 0 0 1 0 0 1073741824 7 0 60.000 +slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 reset slave 'slave1' all; show all slaves status; Connection_name Slave_SQL_State Slave_IO_State Master_Host Master_User Master_Port Connect_Retry Master_Log_File Read_Master_Log_Pos Relay_Log_File Relay_Log_Pos Relay_Master_Log_File Slave_IO_Running Slave_SQL_Running Replicate_Do_DB Replicate_Ignore_DB Replicate_Do_Table Replicate_Ignore_Table Replicate_Wild_Do_Table Replicate_Wild_Ignore_Table Last_Errno Last_Error Skip_Counter Exec_Master_Log_Pos Relay_Log_Space Until_Condition Until_Log_File Until_Log_Pos Master_SSL_Allowed Master_SSL_CA_File Master_SSL_CA_Path Master_SSL_Cert Master_SSL_Cipher Master_SSL_Key Seconds_Behind_Master Master_SSL_Verify_Server_Cert Last_IO_Errno Last_IO_Error Last_SQL_Errno Last_SQL_Error Replicate_Ignore_Server_Ids Master_Server_Id Using_Gtid Retried_transactions Max_relay_log_size Executed_log_entries Slave_received_heartbeats Slave_heartbeat_period Gtid_Pos -slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 0-1-3 +slave2 Slave has read all relay log; waiting for the slave I/O thread to update it Waiting for master to send event 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 Yes Yes 0 0 311 904 None 0 No 0 No 0 0 2 0 0 1073741824 7 0 60.000 stop all slaves; Warnings: Note 1938 SLAVE 'slave2' stopped show all slaves status; Connection_name Slave_SQL_State Slave_IO_State Master_Host Master_User Master_Port Connect_Retry Master_Log_File Read_Master_Log_Pos Relay_Log_File Relay_Log_Pos Relay_Master_Log_File Slave_IO_Running Slave_SQL_Running Replicate_Do_DB Replicate_Ignore_DB Replicate_Do_Table Replicate_Ignore_Table Replicate_Wild_Do_Table Replicate_Wild_Ignore_Table Last_Errno Last_Error Skip_Counter Exec_Master_Log_Pos Relay_Log_Space Until_Condition Until_Log_File Until_Log_Pos Master_SSL_Allowed Master_SSL_CA_File Master_SSL_CA_Path Master_SSL_Cert Master_SSL_Cipher Master_SSL_Key Seconds_Behind_Master Master_SSL_Verify_Server_Cert Last_IO_Errno Last_IO_Error Last_SQL_Errno Last_SQL_Error Replicate_Ignore_Server_Ids Master_Server_Id Using_Gtid Retried_transactions Max_relay_log_size Executed_log_entries Slave_received_heartbeats Slave_heartbeat_period Gtid_Pos -slave2 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 No No 0 0 311 904 None 0 No NULL No 0 0 2 0 0 1073741824 7 0 60.000 0-1-3 +slave2 127.0.0.1 root MYPORT_2 60 master-bin.000001 311 mysqld-relay-bin-slave2.000002 599 master-bin.000001 No No 0 0 311 904 None 0 No NULL No 0 0 2 0 0 1073741824 7 0 60.000 stop all slaves; include/reset_master_slave.inc include/reset_master_slave.inc From 43fe53acc225a2cea07188d142c1c0f8364cc43b Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 17 Apr 2013 14:11:16 +0200 Subject: [PATCH 37/37] Remove forgotten debug printout in test, was a bit too quick there :-( --- mysql-test/t/mysqld--help.test | 1 - 1 file changed, 1 deletion(-) diff --git a/mysql-test/t/mysqld--help.test b/mysql-test/t/mysqld--help.test index c5b9a5d8576..0f3df10ea70 100644 --- a/mysql-test/t/mysqld--help.test +++ b/mysql-test/t/mysqld--help.test @@ -10,7 +10,6 @@ # force symbolic-links=0 (valgrind build has a different default) # ---echo $MYSQLD_BOOTSTRAP_CMD exec $MYSQLD_BOOTSTRAP_CMD --symbolic-links=0 --lower-case-table-names=1 --help --verbose > $MYSQL_TMP_DIR/mysqld--help.txt 2>&1; # The inline perl code below will copy $MYSQL_TMP_DIR/mysqld--help.txt