Commit 445fcaa8 authored by unknown's avatar unknown

MWL#68 efficient partial matching

- Added an initial set of feature-specific test cases
- Handled the special case where the materialized subquery of an
  IN predicates consists of only NULL values.
- Fixed a bug where making Item_in_subselect a constant,
  didn't respect its null_value value.
parent 53681ee5
set @save_optimizer_switch=@@optimizer_switch; set @save_optimizer_switch=@@optimizer_switch;
-------------------------------
Part 1: Feature tests.
-------------------------------
Default for all tests.
set @@optimizer_switch="materialization=on,in_to_exists=off,semijoin=off,subquery_cache=off";
Schema requires partial matching, but data analysis discoveres there is
no need. This is possible only if all outer columns are not NULL.
create table t1 (a1 char(8) not null, a2 char(8) not null);
create table t2 (b1 char(8), b2 char(8));
insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', NULL );
insert into t2 values (NULL , '2 - 02');
insert into t2 values (NULL , NULL );
insert into t2 values ('1 - 02', '2 - 02');
select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);
a1 a2
1 - 01 2 - 01
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
a1 a2 in_res
1 - 00 2 - 00 0
1 - 01 2 - 01 NULL
drop table t1, t2;
NULLs in the outer columns, no NULLs in the suqbuery
create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8) not null, b2 char(8) not null);
insert into t1 values (NULL , '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t1 values (NULL , NULL );
insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 02', '2 - 00');
select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);
a1 a2
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
a1 a2 in_res
NULL 2 - 00 NULL
1 - 01 2 - 01 0
NULL NULL NULL
select * from t1
where (a1, a2) in (select * from t2 where b1 is not null and b2 is not null);
a1 a2
1 - 01 2 - 01
select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;
a1 a2 in_res
NULL 2 - 00 NULL
1 - 01 2 - 01 1
NULL NULL NULL
drop table t1, t2;
All columns require partial matching (no non-null columns)
TODO
Both non-NULL columns and columns with NULLs
TODO
Covering NULL rows
create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8), b2 char(8));
insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 01', NULL );
insert into t2 values (NULL , '2 - 02');
insert into t2 values (NULL , NULL );
insert into t2 values ('1 - 02', '2 - 02');
select * from t1
where (a1, a2) not in (select * from t2);
a1 a2
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
a1 a2 in_res
1 - 00 2 - 00 NULL
1 - 01 2 - 01 NULL
insert into t2 values ('1 - 01', '2 - 01');
select * from t1
where (a1, a2) not in (select * from t2);
a1 a2
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
a1 a2 in_res
1 - 00 2 - 00 NULL
1 - 01 2 - 01 0
select * from t1
where (a1, a2) in (select * from t2);
a1 a2
1 - 01 2 - 01
select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;
a1 a2 in_res
1 - 00 2 - 00 NULL
1 - 01 2 - 01 1
drop table t1, t2;
Covering NULL columns
this case affects only the rowid-merge algorithm
set @@optimizer_switch="partial_match_rowid_merge=on,partial_match_table_scan=off";
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8) not null, b2 char(8), b3 char(8) not null);
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values ('1 - 02', NULL, '3 - 02');
insert into t2 values ('1 - 00', NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
a1 a2 a3
1 - 01 2 - 01 3 - 01
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 1
select * from t1
where (a1, a2, a3) in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 0
drop table t1, t2;
create table t1 (a1 char(8), a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8), b2 char(8), b3 char(8) not null);
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values (NULL, NULL, '3 - x1');
insert into t2 values (NULL, NULL, '3 - 02');
insert into t2 values (NULL, NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
a1 a2 a3
1 - 01 2 - 01 3 - 01
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 1
select * from t1
where (a1, a2, a3) in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 0
drop table t1, t2;
Covering NULL row, and a NULL column
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8), b2 char(8), b3 char(8));
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values (NULL , NULL, NULL );
insert into t2 values ('1 - 00', NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 NULL
select * from t1
where (a1, a2, a3) in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 NULL
drop table t1, t2;
Covering NULL row, and covering NULL columns
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8), b2 char(8), b3 char(8));
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values (NULL, NULL, NULL);
insert into t2 values (NULL, NULL, NULL);
select * from t1
where (a1, a2, a3) not in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 NULL
select * from t1
where (a1, a2, a3) in (select * from t2);
a1 a2 a3
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
a1 a2 a3 in_res
1 - 00 2 - 00 3 - 00 NULL
1 - 01 2 - 01 3 - 01 NULL
drop table t1, t2;
-------------------------------
Part 2: Test cases for bugs.
-------------------------------
drop table if exists t1, t2; drop table if exists t1, t2;
# #
# LP BUG#608744 # LP BUG#608744
......
...@@ -5,6 +5,219 @@ ...@@ -5,6 +5,219 @@
set @save_optimizer_switch=@@optimizer_switch; set @save_optimizer_switch=@@optimizer_switch;
--echo -------------------------------
--echo Part 1: Feature tests.
--echo -------------------------------
--echo Default for all tests.
set @@optimizer_switch="materialization=on,in_to_exists=off,semijoin=off,subquery_cache=off";
--echo
--echo Schema requires partial matching, but data analysis discoveres there is
--echo no need. This is possible only if all outer columns are not NULL.
--echo
create table t1 (a1 char(8) not null, a2 char(8) not null);
create table t2 (b1 char(8), b2 char(8));
insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', NULL );
insert into t2 values (NULL , '2 - 02');
insert into t2 values (NULL , NULL );
insert into t2 values ('1 - 02', '2 - 02');
select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo
--echo NULLs in the outer columns, no NULLs in the suqbuery
--echo
create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8) not null, b2 char(8) not null);
insert into t1 values (NULL , '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t1 values (NULL , NULL );
insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 02', '2 - 00');
select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2) in (select * from t2 where b1 is not null and b2 is not null);
select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo
--echo All columns require partial matching (no non-null columns)
--echo
--echo TODO
--echo
--echo Both non-NULL columns and columns with NULLs
--echo
--echo TODO
--echo
--echo Covering NULL rows
--echo
create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8), b2 char(8));
insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 01', NULL );
insert into t2 values (NULL , '2 - 02');
insert into t2 values (NULL , NULL );
insert into t2 values ('1 - 02', '2 - 02');
select * from t1
where (a1, a2) not in (select * from t2);
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
insert into t2 values ('1 - 01', '2 - 01');
select * from t1
where (a1, a2) not in (select * from t2);
select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2) in (select * from t2);
select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo
--echo Covering NULL columns
--echo
--echo this case affects only the rowid-merge algorithm
set @@optimizer_switch="partial_match_rowid_merge=on,partial_match_table_scan=off";
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8) not null, b2 char(8), b3 char(8) not null);
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values ('1 - 02', NULL, '3 - 02');
insert into t2 values ('1 - 00', NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2, a3) in (select * from t2);
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
drop table t1, t2;
create table t1 (a1 char(8), a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8), b2 char(8), b3 char(8) not null);
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values (NULL, NULL, '3 - x1');
insert into t2 values (NULL, NULL, '3 - 02');
insert into t2 values (NULL, NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2, a3) in (select * from t2);
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo
--echo Covering NULL row, and a NULL column
--echo
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8), b2 char(8), b3 char(8));
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values (NULL , NULL, NULL );
insert into t2 values ('1 - 00', NULL, '3 - 00');
select * from t1
where (a1, a2, a3) not in (select * from t2);
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2, a3) in (select * from t2);
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo
--echo Covering NULL row, and covering NULL columns
--echo
create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8), b2 char(8), b3 char(8));
insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');
insert into t2 values (NULL, NULL, NULL);
insert into t2 values (NULL, NULL, NULL);
select * from t1
where (a1, a2, a3) not in (select * from t2);
select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;
select * from t1
where (a1, a2, a3) in (select * from t2);
select *, (a1, a2, a3) in (select * from t2) as in_res from t1;
drop table t1, t2;
--echo -------------------------------
--echo Part 2: Test cases for bugs.
--echo -------------------------------
--disable_warnings --disable_warnings
drop table if exists t1, t2; drop table if exists t1, t2;
--enable_warnings --enable_warnings
......
...@@ -1406,9 +1406,9 @@ String *Item_in_subselect::val_str(String *str) ...@@ -1406,9 +1406,9 @@ String *Item_in_subselect::val_str(String *str)
bool Item_in_subselect::val_bool() bool Item_in_subselect::val_bool()
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
null_value= was_null= FALSE;
if (forced_const) if (forced_const)
return value; return value;
null_value= was_null= FALSE;
if (exec()) if (exec())
{ {
reset(); reset();
...@@ -4589,6 +4589,20 @@ int subselect_hash_sj_engine::exec() ...@@ -4589,6 +4589,20 @@ int subselect_hash_sj_engine::exec()
has_covering_null_columns= (count_non_null_columns + has_covering_null_columns= (count_non_null_columns +
count_null_only_columns == field_count); count_null_only_columns == field_count);
if (has_covering_null_row && has_covering_null_columns)
{
/*
The whole table consist of only NULL values. The result of IN is
a constant UNKNOWN.
*/
DBUG_ASSERT(tmp_table->file->stats.records == 1);
item_in->value= 0;
item_in->null_value= 1;
item_in->make_const();
item_in->set_first_execution();
DBUG_RETURN(FALSE);
}
if (has_covering_null_row) if (has_covering_null_row)
{ {
DBUG_ASSERT(count_partial_match_columns = field_count); DBUG_ASSERT(count_partial_match_columns = field_count);
......
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