revision-id: 880a22e5c4aa7239b3244ba1b83854955295e849 (mariadb-10.0.36-11-g880a22e5c4a) parent(s): 5fb251642e19c59306c32333dbba669ce160457c author: Varun Gupta committer: Varun Gupta timestamp: 2018-08-27 20:41:35 +0530 message: MDEV-15306: Wrong/Unexpected result with the value optimizer_use_condition_selectivity set to 4 Currently for selectivity calculation we perform range analysis for a column even when we don't have any statistics(EITS). This makes less sense but is used to catch contradiction for WHERE condition. So the solution is to not perform range analysis for selectivity calculation for columns that do not have statistics. --- mysql-test/r/selectivity.result | 44 ++++++++++++++++++++++++++++++++-- mysql-test/r/selectivity_innodb.result | 44 ++++++++++++++++++++++++++++++++-- mysql-test/t/selectivity.test | 36 ++++++++++++++++++++++++++++ sql/opt_range.cc | 10 ++++++-- sql/sql_statistics.h | 29 ++++++++++++++++++---- 5 files changed, 152 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 3e8fb8e2e41..6af4f9a9ace 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -782,9 +782,9 @@ 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 +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 0 +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 drop table t1; @@ -1600,3 +1600,43 @@ drop table t1,t0; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; +# +# MDEV-15306: Wrong/Unexpected result with the value +# optimizer_use_condition_selectivity set to 4 +# +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10); +CREATE FUNCTION f1() RETURNS INT DETERMINISTIC +BEGIN +SET @cnt := @cnt + 1; +RETURN 1; +END;| +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_use_stat_tables= @@use_stat_tables; +set @@use_stat_tables='complementary'; +set @@optimizer_use_condition_selectivity=4; +SET @cnt= 0; +SELECT * FROM t1 WHERE a = f1(); +a +1 +SELECT @cnt; +@cnt +1 +set @@use_stat_tables='preferably'; +analyze table t1 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +SET @cnt := 0; +set @@optimizer_use_condition_selectivity=4; +SELECT * FROM t1 WHERE a = f1(); +a +1 +SELECT @cnt; +@cnt +2 +alter table t1 force; +set @@use_stat_tables= @save_use_stat_tables; +set @@optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +drop table t1; +drop function f1; diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 748ef0cb6ca..e0ed2865f13 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -789,9 +789,9 @@ 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 +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 0 +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 drop table t1; @@ -1604,6 +1604,46 @@ drop table t1,t0; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; +# +# MDEV-15306: Wrong/Unexpected result with the value +# optimizer_use_condition_selectivity set to 4 +# +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10); +CREATE FUNCTION f1() RETURNS INT DETERMINISTIC +BEGIN +SET @cnt := @cnt + 1; +RETURN 1; +END;| +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_use_stat_tables= @@use_stat_tables; +set @@use_stat_tables='complementary'; +set @@optimizer_use_condition_selectivity=4; +SET @cnt= 0; +SELECT * FROM t1 WHERE a = f1(); +a +1 +SELECT @cnt; +@cnt +1 +set @@use_stat_tables='preferably'; +analyze table t1 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +SET @cnt := 0; +set @@optimizer_use_condition_selectivity=4; +SELECT * FROM t1 WHERE a = f1(); +a +1 +SELECT @cnt; +@cnt +2 +alter table t1 force; +set @@use_stat_tables= @save_use_stat_tables; +set @@optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +drop table t1; +drop function f1; set optimizer_switch=@save_optimizer_switch_for_selectivity_test; set @tmp_ust= @@use_stat_tables; set @tmp_oucs= @@optimizer_use_condition_selectivity; diff --git a/mysql-test/t/selectivity.test b/mysql-test/t/selectivity.test index afaa937c360..557a4e92bca 100644 --- a/mysql-test/t/selectivity.test +++ b/mysql-test/t/selectivity.test @@ -1064,3 +1064,39 @@ drop table t1,t0; set histogram_size=@save_histogram_size; set optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; set use_stat_tables=@save_use_stat_tables; + +--echo # +--echo # MDEV-15306: Wrong/Unexpected result with the value +--echo # optimizer_use_condition_selectivity set to 4 +--echo # + +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10); + +delimiter |; +CREATE FUNCTION f1() RETURNS INT DETERMINISTIC +BEGIN + SET @cnt := @cnt + 1; + RETURN 1; +END;| +delimiter ;| +set @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity; +set @save_use_stat_tables= @@use_stat_tables; +set @@use_stat_tables='complementary'; +set @@optimizer_use_condition_selectivity=4; +SET @cnt= 0; +SELECT * FROM t1 WHERE a = f1(); +SELECT @cnt; + +set @@use_stat_tables='preferably'; +analyze table t1 persistent for all; +SET @cnt := 0; +set @@optimizer_use_condition_selectivity=4; +SELECT * FROM t1 WHERE a = f1(); +SELECT @cnt; +alter table t1 force; +set @@use_stat_tables= @save_use_stat_tables; +set @@optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity; +drop table t1; +drop function f1; + diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 734adfbc9d1..ceabac2b744 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -3326,13 +3326,18 @@ bool create_key_parts_for_pseudo_indexes(RANGE_OPT_PARAM *param, for (field_ptr= table->field; *field_ptr; field_ptr++) { - if (bitmap_is_set(used_fields, (*field_ptr)->field_index)) + Column_statistics* col_stats= (*field_ptr)->read_stats; + if (bitmap_is_set(used_fields, (*field_ptr)->field_index) + && col_stats && !col_stats->no_stat_values_provided()) parts++; } KEY_PART *key_part; uint keys= 0; + if (!parts) + return TRUE; + if (!(key_part= (KEY_PART *) alloc_root(param->mem_root, sizeof(KEY_PART) * parts))) return TRUE; @@ -3628,7 +3633,8 @@ 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)) + !bitmap_is_clear_all(used_fields) && + thd->variables.use_stat_tables > 0) { PARAM param; MEM_ROOT alloc; diff --git a/sql/sql_statistics.h b/sql/sql_statistics.h index 6a43e42ab96..a43e0caf0fe 100644 --- a/sql/sql_statistics.h +++ b/sql/sql_statistics.h @@ -342,12 +342,17 @@ class Column_statistics public: Histogram histogram; + + uint32 default_value() + { + return + ((1 << (COLUMN_STAT_HISTOGRAM-COLUMN_STAT_COLUMN_NAME))-1) << + (COLUMN_STAT_COLUMN_NAME+1); + } void set_all_nulls() { - column_stat_nulls= - ((1 << (COLUMN_STAT_HISTOGRAM-COLUMN_STAT_COLUMN_NAME))-1) << - (COLUMN_STAT_COLUMN_NAME+1); + column_stat_nulls= default_value(); } void set_not_null(uint stat_field_no) @@ -393,8 +398,22 @@ class Column_statistics bool min_max_values_are_provided() { return !is_null(COLUMN_STAT_MIN_VALUE) && - !is_null(COLUMN_STAT_MIN_VALUE); - } + !is_null(COLUMN_STAT_MAX_VALUE); + } + /* + This function checks whether the values for the fields of the statistical + tables that were NULL by DEFAULT for a column have changed or not. + + @retval + TRUE: Statistics are not present for a column + FALSE: Statisitics are present for a column + */ + bool no_stat_values_provided() + { + if (column_stat_nulls == default_value()) + return true; + return false; + } };