Commit 04684b77 authored by Sergey Petrunya's avatar Sergey Petrunya

MDEV-4817: Optimizer fails to optimize expression of the form 'FOO' IS NULL

- Modify the way Item_cond::fix_fields() and Item_cond::eval_not_null_tables() 
  calculate bitmap for Item_cond_or::not_null_tables():
  if they see a "... OR inexpensive_const_false_item OR ..." then the item can
  be ignored.
- Updated test results. There can be more warnings produced since parts of WHERE 
  are evaluated more times.
parent 6fb17865
...@@ -1971,6 +1971,7 @@ MIN(t2.pk) ...@@ -1971,6 +1971,7 @@ MIN(t2.pk)
NULL NULL
Warnings: Warnings:
Warning 1292 Truncated incorrect INTEGER value: 'j' Warning 1292 Truncated incorrect INTEGER value: 'j'
Warning 1292 Truncated incorrect INTEGER value: 'j'
EXPLAIN EXPLAIN
SELECT MIN(t2.pk) SELECT MIN(t2.pk)
...@@ -1984,6 +1985,7 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -1984,6 +1985,7 @@ id select_type table type possible_keys key key_len ref rows Extra
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 2 2 MATERIALIZED t2 ALL NULL NULL NULL NULL 2
Warnings: Warnings:
Warning 1292 Truncated incorrect INTEGER value: 'j' Warning 1292 Truncated incorrect INTEGER value: 'j'
Warning 1292 Truncated incorrect INTEGER value: 'j'
# #
# 2) Test that subquery materialization is setup for query with # 2) Test that subquery materialization is setup for query with
......
...@@ -663,9 +663,10 @@ Warning 1365 Division by 0 ...@@ -663,9 +663,10 @@ Warning 1365 Division by 0
Warning 1048 Column 'data' cannot be null Warning 1048 Column 'data' cannot be null
update t1 set data='envelope' where 1/0 or 1; update t1 set data='envelope' where 1/0 or 1;
affected rows: 2 affected rows: 2
info: Rows matched: 2 Changed: 2 Warnings: 3 info: Rows matched: 2 Changed: 2 Warnings: 4
Warnings: Warnings:
Warning 1365 Division by 0 Warning 1365 Division by 0
Warning 1365 Division by 0
Warning 1265 Data truncated for column 'data' at row 1 Warning 1265 Data truncated for column 'data' at row 1
Warning 1265 Data truncated for column 'data' at row 2 Warning 1265 Data truncated for column 'data' at row 2
insert t1 (data) values (default), (1/0), ('dead beef'); insert t1 (data) values (default), (1/0), ('dead beef');
......
...@@ -2117,4 +2117,25 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id ...@@ -2117,4 +2117,25 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id
WHERE a.modified > b.modified or b.modified IS NULL; WHERE a.modified > b.modified or b.modified IS NULL;
id modified id modified
DROP TABLE t1; DROP TABLE t1;
#
# MDEV-4817: Optimizer fails to optimize expression of the form 'FOO' IS NULL
#
create table t0 (a int not null);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
alter table t0 add person_id varchar(255) not null;
create table t1 (pk int not null primary key);
insert into t1 select A.a + 10*B.a from t0 A, t0 B;
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or 'xyz' IS NULL;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or t0.person_id='bar';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
drop table t0, t1;
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
...@@ -14,8 +14,8 @@ EXPLAIN ...@@ -14,8 +14,8 @@ EXPLAIN
SELECT COUNT(*) FROM t2 LEFT JOIN t1 ON t2.fkey = t1.id SELECT COUNT(*) FROM t2 LEFT JOIN t1 ON t2.fkey = t1.id
WHERE t1.name LIKE 'A%' OR FALSE; WHERE t1.name LIKE 'A%' OR FALSE;
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 t2 index NULL fkey 5 NULL 5 Using index 1 SIMPLE t1 index PRIMARY,name name 23 NULL 3 Using where; Using index
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t2.fkey 1 Using where 1 SIMPLE t2 ref fkey fkey 5 test.t1.id 1 Using index
DROP TABLE t1,t2; DROP TABLE t1,t2;
# #
# BUG#58456: Assertion 0 in QUICK_INDEX_MERGE_SELECT::need_sorted_output # BUG#58456: Assertion 0 in QUICK_INDEX_MERGE_SELECT::need_sorted_output
......
...@@ -2128,6 +2128,27 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id ...@@ -2128,6 +2128,27 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id
WHERE a.modified > b.modified or b.modified IS NULL; WHERE a.modified > b.modified or b.modified IS NULL;
id modified id modified
DROP TABLE t1; DROP TABLE t1;
#
# MDEV-4817: Optimizer fails to optimize expression of the form 'FOO' IS NULL
#
create table t0 (a int not null);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
alter table t0 add person_id varchar(255) not null;
create table t1 (pk int not null primary key);
insert into t1 select A.a + 10*B.a from t0 A, t0 B;
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or 'xyz' IS NULL;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or t0.person_id='bar';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index
drop table t0, t1;
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
set join_cache_level=default; set join_cache_level=default;
show variables like 'join_cache_level'; show variables like 'join_cache_level';
......
...@@ -1590,6 +1590,8 @@ NULL ...@@ -1590,6 +1590,8 @@ NULL
Warnings: Warnings:
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
SELECT str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20'; SELECT str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20';
str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20' str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20'
1 1
......
...@@ -1592,6 +1592,8 @@ NULL ...@@ -1592,6 +1592,8 @@ NULL
Warnings: Warnings:
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
Warning 1411 Incorrect datetime value: '2007-20-00' for function str_to_date
SELECT str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20'; SELECT str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20';
str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20' str_to_date('2007-10-00', '%Y-%m-%d') BETWEEN '' AND '2007/10/20'
1 1
......
...@@ -3129,6 +3129,7 @@ WHERE table1 .`col_varchar_key` ) field10 ...@@ -3129,6 +3129,7 @@ WHERE table1 .`col_varchar_key` ) field10
1 NULL f 1 NULL f
Warnings: Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'f' Warning 1292 Truncated incorrect DOUBLE value: 'f'
Warning 1292 Truncated incorrect DOUBLE value: 'f'
SET @@optimizer_switch = 'subquery_cache=on'; SET @@optimizer_switch = 'subquery_cache=on';
/* cache is on */ SELECT COUNT( DISTINCT table2 .`col_int_key` ) , ( /* cache is on */ SELECT COUNT( DISTINCT table2 .`col_int_key` ) , (
SELECT SUBQUERY2_t1 .`col_int_key` SELECT SUBQUERY2_t1 .`col_int_key`
...@@ -3144,6 +3145,7 @@ WHERE table1 .`col_varchar_key` ) field10 ...@@ -3144,6 +3145,7 @@ WHERE table1 .`col_varchar_key` ) field10
1 NULL f 1 NULL f
Warnings: Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'f' Warning 1292 Truncated incorrect DOUBLE value: 'f'
Warning 1292 Truncated incorrect DOUBLE value: 'f'
drop table t1,t2,t3,t4; drop table t1,t2,t3,t4;
set @@optimizer_switch= default; set @@optimizer_switch= default;
#launchpad BUG#611625 #launchpad BUG#611625
......
...@@ -1670,4 +1670,21 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id ...@@ -1670,4 +1670,21 @@ SELECT a.* FROM t1 a LEFT JOIN t1 b ON a.id = b.id
DROP TABLE t1; DROP TABLE t1;
--echo #
--echo # MDEV-4817: Optimizer fails to optimize expression of the form 'FOO' IS NULL
--echo #
create table t0 (a int not null);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
alter table t0 add person_id varchar(255) not null;
create table t1 (pk int not null primary key);
insert into t1 select A.a + 10*B.a from t0 A, t0 B;
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or 'xyz' IS NULL;
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo';
explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or t0.person_id='bar';
drop table t0, t1;
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
...@@ -4301,12 +4301,40 @@ Item_cond::fix_fields(THD *thd, Item **ref) ...@@ -4301,12 +4301,40 @@ Item_cond::fix_fields(THD *thd, Item **ref)
return TRUE; /* purecov: inspected */ return TRUE; /* purecov: inspected */
used_tables_cache|= item->used_tables(); used_tables_cache|= item->used_tables();
if (item->const_item()) if (item->const_item())
and_tables_cache= (table_map) 0; {
if (!item->is_expensive() && item->val_int() == 0)
{
/*
This is "... OR false_cond OR ..."
In this case, false_cond has no effect on cond_or->not_null_tables()
*/
}
else
{
/*
This is "... OR const_cond OR ..."
In this case, cond_or->not_null_tables()=0, because the condition
some_cond_or might be true regardless of what tables are
NULL-complemented.
*/
and_tables_cache= (table_map) 0;
}
}
else else
{ {
table_map tmp_table_map= item->not_null_tables(); /*
not_null_tables_cache|= tmp_table_map; If an item is a
and_tables_cache&= tmp_table_map; - constant
- inexpensive
- its value is 0
then we don't need to account it in not_null_tables_cache
*/
//if (!(item->const_item() && !item->is_expensive() ))
{
table_map tmp_table_map= item->not_null_tables();
not_null_tables_cache|= tmp_table_map;
and_tables_cache&= tmp_table_map;
}
const_item_cache= FALSE; const_item_cache= FALSE;
} }
...@@ -4334,7 +4362,25 @@ Item_cond::eval_not_null_tables(uchar *opt_arg) ...@@ -4334,7 +4362,25 @@ Item_cond::eval_not_null_tables(uchar *opt_arg)
{ {
table_map tmp_table_map; table_map tmp_table_map;
if (item->const_item()) if (item->const_item())
and_tables_cache= (table_map) 0; {
if (!item->is_expensive() && item->val_int() == 0)
{
/*
This is "... OR false_cond OR ..."
In this case, false_cond has no effect on cond_or->not_null_tables()
*/
}
else
{
/*
This is "... OR const_cond OR ..."
In this case, cond_or->not_null_tables()=0, because the condition
some_cond_or might be true regardless of what tables are
NULL-complemented.
*/
and_tables_cache= (table_map) 0;
}
}
else else
{ {
tmp_table_map= item->not_null_tables(); tmp_table_map= item->not_null_tables();
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment