1
0
mirror of https://github.com/MariaDB/server.git synced 2025-07-30 16:24:05 +03:00

MDEV-12721 Wrong execution plan for WHERE (date_field <=> timestamp_expr AND TRUE)

This commit is contained in:
Alexander Barkov
2017-05-07 17:44:27 +04:00
parent 4e9022b48b
commit 02ada41744
4 changed files with 102 additions and 37 deletions

View File

@ -429,17 +429,26 @@ select @a;
# #
# BUG LP:1008487 virtual bool Item_cache::is_expensive(): Assertion `example' failed # BUG LP:1008487 virtual bool Item_cache::is_expensive(): Assertion `example' failed
# #
SET TIMESTAMP=UNIX_TIMESTAMP('2017-01-03 00:00:00');
create table t1(a date,key(a)); create table t1(a date,key(a));
insert into t1 values ('2012-01-01'),('2012-02-02'); insert into t1 values ('2012-01-01'),('2012-02-02');
explain explain
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1; select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1_0 ref a a 4 const 0 Using where; Using index 1 SIMPLE t1_0 ref a a 4 const 1 Using where; Using index
1 SIMPLE t2 index NULL a 4 NULL 2 Using index; Using join buffer (flat, BNL join) 1 SIMPLE t2 index NULL a 4 NULL 2 Using index; Using join buffer (flat, BNL join)
1 SIMPLE t1 index NULL a 4 NULL 2 Using index; Using join buffer (incremental, BNL join) 1 SIMPLE t1 index NULL a 4 NULL 2 Using index; Using join buffer (incremental, BNL join)
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1; select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
1 1
SET TIMESTAMP=UNIX_TIMESTAMP('2012-01-03 00:00:01');
explain
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
1
drop table t1; drop table t1;
SET TIMESTAMP=DEFAULT;
# #
# MDEV-9521 Least function returns 0000-00-00 for null date columns instead of null # MDEV-9521 Least function returns 0000-00-00 for null date columns instead of null
# MDEV-9972 Least function retuns date in date time format # MDEV-9972 Least function retuns date in date time format
@ -845,3 +854,27 @@ DROP TABLE t1;
# #
# End of 10.1 tests # End of 10.1 tests
# #
#
# Start of 10.3 tests
#
#
# MDEV-12721 Wrong execution plan for WHERE (date_field <=> timestamp_expr AND TRUE)
#
CREATE TABLE t1(a DATE,KEY(a));
INSERT INTO t1 VALUES ('2012-01-01'),('2012-02-02');
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP'2001-01-01 00:00:01' AND TRUE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP('2001-01-01', '00:00:01') AND TRUE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP'2001-01-01 00:00:00' AND TRUE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref a a 4 const 1 Using where; Using index
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP('2001-01-01', '00:00:00') AND TRUE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref a a 4 const 1 Using where; Using index
DROP TABLE t1;
#
# End of 10.3 tests
#

View File

@ -369,12 +369,18 @@ select @a;
--echo # --echo #
--echo # BUG LP:1008487 virtual bool Item_cache::is_expensive(): Assertion `example' failed --echo # BUG LP:1008487 virtual bool Item_cache::is_expensive(): Assertion `example' failed
--echo # --echo #
SET TIMESTAMP=UNIX_TIMESTAMP('2017-01-03 00:00:00');
create table t1(a date,key(a)); create table t1(a date,key(a));
insert into t1 values ('2012-01-01'),('2012-02-02'); insert into t1 values ('2012-01-01'),('2012-02-02');
explain explain
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1; select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1; select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
SET TIMESTAMP=UNIX_TIMESTAMP('2012-01-03 00:00:01');
explain
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
select 1 from t1 as t1_0 inner join t1 as t2 on (t1_0.a <=> now()) join t1 on 1;
drop table t1; drop table t1;
SET TIMESTAMP=DEFAULT;
--echo # --echo #
--echo # MDEV-9521 Least function returns 0000-00-00 for null date columns instead of null --echo # MDEV-9521 Least function returns 0000-00-00 for null date columns instead of null
@ -580,3 +586,22 @@ DROP TABLE t1;
--echo # --echo #
--echo # End of 10.1 tests --echo # End of 10.1 tests
--echo # --echo #
--echo #
--echo # Start of 10.3 tests
--echo #
--echo #
--echo # MDEV-12721 Wrong execution plan for WHERE (date_field <=> timestamp_expr AND TRUE)
--echo #
CREATE TABLE t1(a DATE,KEY(a));
INSERT INTO t1 VALUES ('2012-01-01'),('2012-02-02');
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP'2001-01-01 00:00:01' AND TRUE;
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP('2001-01-01', '00:00:01') AND TRUE;
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP'2001-01-01 00:00:00' AND TRUE;
EXPLAIN SELECT 1 FROM t1 WHERE t1.a <=> TIMESTAMP('2001-01-01', '00:00:00') AND TRUE;
DROP TABLE t1;
--echo #
--echo # End of 10.3 tests
--echo #

View File

@ -8030,33 +8030,53 @@ Item_bool_func::get_mm_leaf(RANGE_OPT_PARAM *param,
field->type_handler() == &type_handler_set) field->type_handler() == &type_handler_set)
{ {
if (type == EQ_FUNC || type == EQUAL_FUNC) if (type == EQ_FUNC || type == EQUAL_FUNC)
{ tree= new (alloc) SEL_ARG_IMPOSSIBLE(field);
tree= new (alloc) SEL_ARG(field, 0, 0);
tree->type= SEL_ARG::IMPOSSIBLE;
}
goto end; goto end;
} }
if (err == 2 && field->cmp_type() == STRING_RESULT) if (err == 2 && field->cmp_type() == STRING_RESULT)
{ {
if (type == EQ_FUNC || type == EQUAL_FUNC) if (type == EQ_FUNC || type == EQUAL_FUNC)
{ tree= new (alloc) SEL_ARG_IMPOSSIBLE(field);
tree= new (alloc) SEL_ARG(field, 0, 0);
tree->type= SEL_ARG::IMPOSSIBLE;
}
else else
tree= NULL; /* Cannot infer anything */ tree= NULL; /* Cannot infer anything */
goto end; goto end;
} }
if (field->cmp_type() != value->result_type()) if (err == 3 && field->type() == FIELD_TYPE_DATE)
{
/*
We were saving DATETIME into a DATE column, the conversion went ok
but a non-zero time part was cut off.
In MySQL's SQL dialect, DATE and DATETIME are compared as datetime
values. Index over a DATE column uses DATE comparison. Changing
from one comparison to the other is possible:
datetime(date_col)< '2007-12-10 12:34:55' -> date_col<='2007-12-10'
datetime(date_col)<='2007-12-10 12:34:55' -> date_col<='2007-12-10'
datetime(date_col)> '2007-12-10 12:34:55' -> date_col>='2007-12-10'
datetime(date_col)>='2007-12-10 12:34:55' -> date_col>='2007-12-10'
but we'll need to convert '>' to '>=' and '<' to '<='. This will
be done together with other types at the end of this function
(grep for stored_field_cmp_to_item)
*/
if (type == EQ_FUNC || type == EQUAL_FUNC)
{
tree= new (alloc) SEL_ARG_IMPOSSIBLE(field);
goto end;
}
// Continue with processing non-equality ranges
}
else if (field->cmp_type() != value->result_type())
{ {
if ((type == EQ_FUNC || type == EQUAL_FUNC) && if ((type == EQ_FUNC || type == EQUAL_FUNC) &&
value->result_type() == item_cmp_type(field->result_type(), value->result_type() == item_cmp_type(field->result_type(),
value->result_type())) value->result_type()))
{ {
tree= new (alloc) SEL_ARG(field, 0, 0); tree= new (alloc) SEL_ARG_IMPOSSIBLE(field);
tree->type= SEL_ARG::IMPOSSIBLE;
goto end; goto end;
} }
else else
@ -8066,31 +8086,7 @@ Item_bool_func::get_mm_leaf(RANGE_OPT_PARAM *param,
for the cases like int_field > 999999999999999999999999 as well. for the cases like int_field > 999999999999999999999999 as well.
*/ */
tree= 0; tree= 0;
if (err == 3 && field->type() == FIELD_TYPE_DATE && goto end;
(type == GT_FUNC || type == GE_FUNC ||
type == LT_FUNC || type == LE_FUNC) )
{
/*
We were saving DATETIME into a DATE column, the conversion went ok
but a non-zero time part was cut off.
In MySQL's SQL dialect, DATE and DATETIME are compared as datetime
values. Index over a DATE column uses DATE comparison. Changing
from one comparison to the other is possible:
datetime(date_col)< '2007-12-10 12:34:55' -> date_col<='2007-12-10'
datetime(date_col)<='2007-12-10 12:34:55' -> date_col<='2007-12-10'
datetime(date_col)> '2007-12-10 12:34:55' -> date_col>='2007-12-10'
datetime(date_col)>='2007-12-10 12:34:55' -> date_col>='2007-12-10'
but we'll need to convert '>' to '>=' and '<' to '<='. This will
be done together with other types at the end of this function
(grep for stored_field_cmp_to_item)
*/
}
else
goto end;
} }
} }

View File

@ -594,6 +594,17 @@ public:
}; };
class SEL_ARG_IMPOSSIBLE: public SEL_ARG
{
public:
SEL_ARG_IMPOSSIBLE(Field *field)
:SEL_ARG(field, 0, 0)
{
type= SEL_ARG::IMPOSSIBLE;
}
};
class RANGE_OPT_PARAM class RANGE_OPT_PARAM
{ {
public: public: