mirror of
https://github.com/MariaDB/server.git
synced 2025-01-22 06:44:16 +01:00
db4738a18a
The bug was a result of missing logic to handle the case when there are 'expensive' predicates that are not evaluated during constant table optimization. Such is the case for the IN predicate, which is considered expensive if it is computed via materialization. In general this bug can be triggered with any expensive predicate instead of IN. When FALSE constant predicates are not evaluated during constant optimization, the execution path changes so that instead of setting JOIN::zero_result_cause after make_join_select, and exiting JOIN::exec via the call to return_zero_rows(), execution ends in JOIN::exec in the branch: if (join->tables == join->const_tables) { ... else if (join->send_row_on_empty_set()) ... rc= join->result->send_data(*columns_list); } Unlike return_zero_rows(), this branch didn't evaluate the having clause of the query. The patch adds a call to evaluate the HAVING clause of a query even when all tables are constant, because even for an empty result set some aggregate functions may produce a NULL value.
945 lines
34 KiB
Text
945 lines
34 KiB
Text
#
|
|
# Hash semi-join regression tests
|
|
# (WL#1110: Subquery optimization: materialization)
|
|
#
|
|
|
|
--disable_warnings
|
|
drop table if exists t1, t2, t3, t1i, t2i, t3i;
|
|
drop view if exists v1, v2, v1m, v2m;
|
|
--enable_warnings
|
|
|
|
create table t1 (a1 char(8), a2 char(8));
|
|
create table t2 (b1 char(8), b2 char(8));
|
|
create table t3 (c1 char(8), c2 char(8));
|
|
|
|
insert into t1 values ('1 - 00', '2 - 00');
|
|
insert into t1 values ('1 - 01', '2 - 01');
|
|
insert into t1 values ('1 - 02', '2 - 02');
|
|
|
|
insert into t2 values ('1 - 01', '2 - 01');
|
|
insert into t2 values ('1 - 01', '2 - 01');
|
|
insert into t2 values ('1 - 02', '2 - 02');
|
|
insert into t2 values ('1 - 02', '2 - 02');
|
|
insert into t2 values ('1 - 03', '2 - 03');
|
|
|
|
insert into t3 values ('1 - 01', '2 - 01');
|
|
insert into t3 values ('1 - 02', '2 - 02');
|
|
insert into t3 values ('1 - 03', '2 - 03');
|
|
insert into t3 values ('1 - 04', '2 - 04');
|
|
|
|
# Indexed columns
|
|
create table t1i (a1 char(8), a2 char(8));
|
|
create table t2i (b1 char(8), b2 char(8));
|
|
create table t3i (c1 char(8), c2 char(8));
|
|
create index it1i1 on t1i (a1);
|
|
create index it1i2 on t1i (a2);
|
|
create index it1i3 on t1i (a1, a2);
|
|
|
|
create index it2i1 on t2i (b1);
|
|
create index it2i2 on t2i (b2);
|
|
create index it2i3 on t2i (b1, b2);
|
|
|
|
create index it3i1 on t3i (c1);
|
|
create index it3i2 on t3i (c2);
|
|
create index it3i3 on t3i (c1, c2);
|
|
|
|
insert into t1i select * from t1;
|
|
insert into t2i select * from t2;
|
|
insert into t3i select * from t3;
|
|
|
|
# force the use of materialization
|
|
set @@optimizer_switch='semijoin=off';
|
|
|
|
/******************************************************************************
|
|
* Simple tests.
|
|
******************************************************************************/
|
|
# non-indexed nullable fields
|
|
explain extended
|
|
select * from t1 where a1 in (select b1 from t2 where b1 > '0');
|
|
select * from t1 where a1 in (select b1 from t2 where b1 > '0');
|
|
|
|
explain extended
|
|
select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1);
|
|
select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1);
|
|
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2);
|
|
select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2);
|
|
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1);
|
|
select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1);
|
|
|
|
# indexed columns
|
|
explain extended
|
|
select * from t1i where a1 in (select b1 from t2i where b1 > '0');
|
|
select * from t1i where a1 in (select b1 from t2i where b1 > '0');
|
|
|
|
explain extended
|
|
select * from t1i where a1 in (select b1 from t2i where b1 > '0' group by b1);
|
|
select * from t1i where a1 in (select b1 from t2i where b1 > '0' group by b1);
|
|
|
|
explain extended
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i where b1 > '0');
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i where b1 > '0');
|
|
|
|
explain extended
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i where b1 > '0' group by b1, b2);
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i where b1 > '0' group by b1, b2);
|
|
|
|
explain extended
|
|
select * from t1i where (a1, a2) in (select b1, min(b2) from t2i where b1 > '0' group by b1);
|
|
select * from t1i where (a1, a2) in (select b1, min(b2) from t2i where b1 > '0' group by b1);
|
|
|
|
# BUG#31639: Wrong plan for uncorrelated subquery when loose scan is applicable.
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select b1, max(b2) from t2i group by b1);
|
|
select * from t1 where (a1, a2) in (select b1, max(b2) from t2i group by b1);
|
|
|
|
prepare st1 from "explain select * from t1 where (a1, a2) in (select b1, max(b2) from t2i group by b1)";
|
|
execute st1;
|
|
execute st1;
|
|
prepare st2 from "select * from t1 where (a1, a2) in (select b1, max(b2) from t2i group by b1)";
|
|
execute st2;
|
|
execute st2;
|
|
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select b1, min(b2) from t2i where b1 > '0' group by b1);
|
|
select * from t1 where (a1, a2) in (select b1, min(b2) from t2i where b1 > '0' group by b1);
|
|
-- error 1235
|
|
select * from t1 where (a1, a2) in (select b1, min(b2) from t2i limit 1,1);
|
|
|
|
# test re-optimization/re-execution with different execution methods
|
|
# prepare once, exec with different modes
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
prepare st1 from
|
|
"select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)";
|
|
set @@optimizer_switch='default,materialization=off';
|
|
execute st1;
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
execute st1;
|
|
|
|
set @@optimizer_switch='default,materialization=off';
|
|
prepare st1 from
|
|
"select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)";
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
execute st1;
|
|
set @@optimizer_switch='default,materialization=off';
|
|
execute st1;
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
|
|
# materialize the result of ORDER BY
|
|
# non-indexed fields
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select b1, b2 from t2 order by b1, b2);
|
|
select * from t1 where (a1, a2) in (select b1, b2 from t2 order by b1, b2);
|
|
# indexed fields
|
|
explain extended
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i order by b1, b2);
|
|
select * from t1i where (a1, a2) in (select b1, b2 from t2i order by b1, b2);
|
|
|
|
/******************************************************************************
|
|
* Views, UNIONs, several levels of nesting.
|
|
******************************************************************************/
|
|
# materialize the result of subquery over temp-table view
|
|
|
|
create algorithm=merge view v1 as
|
|
select b1, c2 from t2, t3 where b2 > c2;
|
|
|
|
create algorithm=merge view v2 as
|
|
select b1, c2 from t2, t3 group by b2, c2;
|
|
|
|
create algorithm=temptable view v1m as
|
|
select b1, c2 from t2, t3 where b2 > c2;
|
|
|
|
create algorithm=temptable view v2m as
|
|
select b1, c2 from t2, t3 group by b2, c2;
|
|
|
|
select * from v1 where (c2, b1) in (select c2, b1 from v2 where b1 is not null);
|
|
select * from v1 where (c2, b1) in (select distinct c2, b1 from v2 where b1 is not null);
|
|
|
|
select * from v1m where (c2, b1) in (select c2, b1 from v2m where b1 is not null);
|
|
select * from v1m where (c2, b1) in (select distinct c2, b1 from v2m where b1 is not null);
|
|
|
|
drop view v1, v2, v1m, v2m;
|
|
|
|
# nested subqueries, views
|
|
explain extended
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2 where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2 where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
|
|
explain extended
|
|
select * from t1i
|
|
where (a1, a2) in (select b1, b2 from t2i where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3i
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
select * from t1i
|
|
where (a1, a2) in (select b1, b2 from t2i where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3i
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
|
|
explain extended
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 where c2 LIKE '%02') or
|
|
b2 in (select c2 from t3 where c2 LIKE '%03')) and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 where c2 LIKE '%02') or
|
|
b2 in (select c2 from t3 where c2 LIKE '%03')) and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
|
|
# as above with correlated innermost subquery
|
|
explain extended
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 t3a where c1 = a1) or
|
|
b2 in (select c2 from t3 t3b where c2 LIKE '%03')) and
|
|
(a1, a2) in (select c1, c2 from t3 t3c
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 t3a where c1 = a1) or
|
|
b2 in (select c2 from t3 t3b where c2 LIKE '%03')) and
|
|
(a1, a2) in (select c1, c2 from t3 t3c
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
|
|
|
|
# multiple levels of nesting subqueries, unions
|
|
explain extended
|
|
(select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 where c2 LIKE '%02') or
|
|
b2 in (select c2 from t3 where c2 LIKE '%03')
|
|
group by b1, b2) and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')))
|
|
UNION
|
|
(select * from t1i
|
|
where (a1, a2) in (select b1, b2 from t2i where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3i
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')));
|
|
|
|
(select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 where c2 LIKE '%02') or
|
|
b2 in (select c2 from t3 where c2 LIKE '%03')
|
|
group by b1, b2) and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')))
|
|
UNION
|
|
(select * from t1i
|
|
where (a1, a2) in (select b1, b2 from t2i where b1 > '0') and
|
|
(a1, a2) in (select c1, c2 from t3i
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')));
|
|
|
|
|
|
# UNION of subqueries as a subquery (thus it is not computed via materialization)
|
|
explain extended
|
|
select * from t1
|
|
where (a1, a2) in (select * from t1 where a1 > '0' UNION select * from t2 where b1 < '9') and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
select * from t1
|
|
where (a1, a2) in (select * from t1 where a1 > '0' UNION select * from t2 where b1 < '9') and
|
|
(a1, a2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0'));
|
|
# as above, with a join conditon between the outer references
|
|
explain extended
|
|
select * from t1, t3
|
|
where (a1, a2) in (select * from t1 where a1 > '0' UNION select * from t2 where b1 < '9') and
|
|
(c1, c2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')) and
|
|
a1 = c1;
|
|
select * from t1, t3
|
|
where (a1, a2) in (select * from t1 where a1 > '0' UNION select * from t2 where b1 < '9') and
|
|
(c1, c2) in (select c1, c2 from t3
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0')) and
|
|
a1 = c1;
|
|
|
|
|
|
/******************************************************************************
|
|
* Negative tests, where materialization should not be applied.
|
|
******************************************************************************/
|
|
# UNION in a subquery
|
|
explain extended
|
|
select * from t3
|
|
where c1 in (select a1 from t1 where a1 > '0' UNION select b1 from t2 where b1 < '9');
|
|
select * from t3
|
|
where c1 in (select a1 from t1 where a1 > '0' UNION select b1 from t2 where b1 < '9');
|
|
|
|
# correlation
|
|
explain extended
|
|
select * from t1
|
|
where (a1, a2) in (select b1, b2 from t2
|
|
where b2 in (select c2 from t3 t3a where c1 = a1) or
|
|
b2 in (select c2 from t3 t3b where c2 LIKE '%03')) and
|
|
(a1, a2) in (select c1, c2 from t3 t3c
|
|
where (c1, c2) in (select b1, b2 from t2i where b2 > '0' or b2 = a2));
|
|
|
|
# subquery has no tables
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select '1 - 01', '2 - 01');
|
|
select * from t1 where (a1, a2) in (select '1 - 01', '2 - 01');
|
|
explain extended
|
|
select * from t1 where (a1, a2) in (select '1 - 01', '2 - 01' from dual);
|
|
select * from t1 where (a1, a2) in (select '1 - 01', '2 - 01' from dual);
|
|
|
|
|
|
/******************************************************************************
|
|
* Subqueries in other uncovered clauses.
|
|
******************************************************************************/
|
|
|
|
/* SELECT clause */
|
|
select ((a1,a2) IN (select * from t2 where b2 > '0')) IS NULL from t1;
|
|
|
|
/* GROUP BY clause */
|
|
create table columns (col int key);
|
|
insert into columns values (1), (2);
|
|
|
|
explain extended
|
|
select * from t1 group by (select col from columns limit 1);
|
|
select * from t1 group by (select col from columns limit 1);
|
|
|
|
explain extended
|
|
select * from t1 group by (a1 in (select col from columns));
|
|
select * from t1 group by (a1 in (select col from columns));
|
|
|
|
/* ORDER BY clause */
|
|
explain extended
|
|
select * from t1 order by (select col from columns limit 1);
|
|
select * from t1 order by (select col from columns limit 1);
|
|
|
|
/******************************************************************************
|
|
* Column types/sizes that affect materialization.
|
|
******************************************************************************/
|
|
|
|
/*
|
|
Test that BLOBs are not materialized (except when arguments of some functions).
|
|
*/
|
|
# force materialization to be always considered
|
|
set @@optimizer_switch='semijoin=off';
|
|
set @prefix_len = 6;
|
|
|
|
# BLOB == 16 (small blobs that could be stored in HEAP tables)
|
|
set @blob_len = 16;
|
|
set @suffix_len = @blob_len - @prefix_len;
|
|
|
|
create table t1_16 (a1 blob(16), a2 blob(16));
|
|
create table t2_16 (b1 blob(16), b2 blob(16));
|
|
create table t3_16 (c1 blob(16), c2 blob(16));
|
|
|
|
insert into t1_16 values
|
|
(concat('1 - 00', repeat('x', @suffix_len)), concat('2 - 00', repeat('x', @suffix_len)));
|
|
insert into t1_16 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t1_16 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
|
|
insert into t2_16 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t2_16 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t2_16 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
|
|
insert into t3_16 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t3_16 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t3_16 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
insert into t3_16 values
|
|
(concat('1 - 04', repeat('x', @suffix_len)), concat('2 - 04', repeat('x', @suffix_len)));
|
|
|
|
# single value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select b1 from t2_16 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select b1 from t2_16 where b1 > '0');
|
|
|
|
# row value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where (a1,a2) in (select b1, b2 from t2_16 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where (a1,a2) in (select b1, b2 from t2_16 where b1 > '0');
|
|
|
|
# string function with a blob argument, the return type may be != blob
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select substring(b1,1,16) from t2_16 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select substring(b1,1,16) from t2_16 where b1 > '0');
|
|
|
|
# group_concat with a blob argument - depends on
|
|
# the variable group_concat_max_len, and
|
|
# convert_blob_length == max_len*collation->mbmaxlen > CONVERT_IF_BIGGER_TO_BLOB
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select group_concat(b1) from t2_16 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select group_concat(b1) from t2_16 group by b2);
|
|
|
|
set @@group_concat_max_len = 256; # anything < (CONVERT_IF_BIGGER_TO_BLOB = 512)
|
|
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select group_concat(b1) from t2_16 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_16
|
|
where a1 in (select group_concat(b1) from t2_16 group by b2);
|
|
|
|
# BLOB column at the second (intermediate) level of nesting
|
|
explain extended
|
|
select * from t1
|
|
where concat(a1,'x') IN
|
|
(select left(a1,8) from t1_16
|
|
where (a1, a2) IN
|
|
(select t2_16.b1, t2_16.b2 from t2_16, t2
|
|
where t2.b2 = substring(t2_16.b2,1,6) and
|
|
t2.b1 IN (select c1 from t3 where c2 > '0')));
|
|
|
|
|
|
drop table t1_16, t2_16, t3_16;
|
|
|
|
|
|
# BLOB == 512 (CONVERT_IF_BIGGER_TO_BLOB == 512)
|
|
set @blob_len = 512;
|
|
set @suffix_len = @blob_len - @prefix_len;
|
|
|
|
create table t1_512 (a1 blob(512), a2 blob(512));
|
|
create table t2_512 (b1 blob(512), b2 blob(512));
|
|
create table t3_512 (c1 blob(512), c2 blob(512));
|
|
|
|
insert into t1_512 values
|
|
(concat('1 - 00', repeat('x', @suffix_len)), concat('2 - 00', repeat('x', @suffix_len)));
|
|
insert into t1_512 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t1_512 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
|
|
insert into t2_512 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t2_512 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t2_512 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
|
|
insert into t3_512 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t3_512 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t3_512 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
insert into t3_512 values
|
|
(concat('1 - 04', repeat('x', @suffix_len)), concat('2 - 04', repeat('x', @suffix_len)));
|
|
|
|
# single value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select b1 from t2_512 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select b1 from t2_512 where b1 > '0');
|
|
|
|
# row value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where (a1,a2) in (select b1, b2 from t2_512 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where (a1,a2) in (select b1, b2 from t2_512 where b1 > '0');
|
|
|
|
# string function with a blob argument, the return type may be != blob
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select substring(b1,1,512) from t2_512 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select substring(b1,1,512) from t2_512 where b1 > '0');
|
|
|
|
# group_concat with a blob argument - depends on
|
|
# the variable group_concat_max_len, and
|
|
# convert_blob_length == max_len*collation->mbmaxlen > CONVERT_IF_BIGGER_TO_BLOB
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select group_concat(b1) from t2_512 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select group_concat(b1) from t2_512 group by b2);
|
|
|
|
set @@group_concat_max_len = 256; # anything < (CONVERT_IF_BIGGER_TO_BLOB = 512)
|
|
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select group_concat(b1) from t2_512 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_512
|
|
where a1 in (select group_concat(b1) from t2_512 group by b2);
|
|
|
|
drop table t1_512, t2_512, t3_512;
|
|
|
|
|
|
# BLOB == 1024 (group_concat_max_len == 1024)
|
|
set @blob_len = 1024;
|
|
set @suffix_len = @blob_len - @prefix_len;
|
|
|
|
create table t1_1024 (a1 blob(1024), a2 blob(1024));
|
|
create table t2_1024 (b1 blob(1024), b2 blob(1024));
|
|
create table t3_1024 (c1 blob(1024), c2 blob(1024));
|
|
|
|
insert into t1_1024 values
|
|
(concat('1 - 00', repeat('x', @suffix_len)), concat('2 - 00', repeat('x', @suffix_len)));
|
|
insert into t1_1024 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t1_1024 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
|
|
insert into t2_1024 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t2_1024 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t2_1024 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
|
|
insert into t3_1024 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t3_1024 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t3_1024 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
insert into t3_1024 values
|
|
(concat('1 - 04', repeat('x', @suffix_len)), concat('2 - 04', repeat('x', @suffix_len)));
|
|
|
|
# single value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select b1 from t2_1024 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select b1 from t2_1024 where b1 > '0');
|
|
|
|
# row value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0');
|
|
|
|
# string function with a blob argument, the return type may be != blob
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0');
|
|
|
|
# group_concat with a blob argument - depends on
|
|
# the variable group_concat_max_len, and
|
|
# convert_blob_length == max_len*collation->mbmaxlen > CONVERT_IF_BIGGER_TO_BLOB
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select group_concat(b1) from t2_1024 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select group_concat(b1) from t2_1024 group by b2);
|
|
|
|
set @@group_concat_max_len = 256; # anything < (CONVERT_IF_BIGGER_TO_BLOB = 1024)
|
|
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select group_concat(b1) from t2_1024 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1024
|
|
where a1 in (select group_concat(b1) from t2_1024 group by b2);
|
|
|
|
drop table t1_1024, t2_1024, t3_1024;
|
|
|
|
|
|
# BLOB == 1025
|
|
set @blob_len = 1025;
|
|
set @suffix_len = @blob_len - @prefix_len;
|
|
|
|
create table t1_1025 (a1 blob(1025), a2 blob(1025));
|
|
create table t2_1025 (b1 blob(1025), b2 blob(1025));
|
|
create table t3_1025 (c1 blob(1025), c2 blob(1025));
|
|
|
|
insert into t1_1025 values
|
|
(concat('1 - 00', repeat('x', @suffix_len)), concat('2 - 00', repeat('x', @suffix_len)));
|
|
insert into t1_1025 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t1_1025 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
|
|
insert into t2_1025 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t2_1025 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t2_1025 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
|
|
insert into t3_1025 values
|
|
(concat('1 - 01', repeat('x', @suffix_len)), concat('2 - 01', repeat('x', @suffix_len)));
|
|
insert into t3_1025 values
|
|
(concat('1 - 02', repeat('x', @suffix_len)), concat('2 - 02', repeat('x', @suffix_len)));
|
|
insert into t3_1025 values
|
|
(concat('1 - 03', repeat('x', @suffix_len)), concat('2 - 03', repeat('x', @suffix_len)));
|
|
insert into t3_1025 values
|
|
(concat('1 - 04', repeat('x', @suffix_len)), concat('2 - 04', repeat('x', @suffix_len)));
|
|
|
|
# single value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select b1 from t2_1025 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select b1 from t2_1025 where b1 > '0');
|
|
|
|
# row value transformer
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where (a1,a2) in (select b1, b2 from t2_1025 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where (a1,a2) in (select b1, b2 from t2_1025 where b1 > '0');
|
|
|
|
# string function with a blob argument, the return type may be != blob
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select substring(b1,1,1025) from t2_1025 where b1 > '0');
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select substring(b1,1,1025) from t2_1025 where b1 > '0');
|
|
|
|
# group_concat with a blob argument - depends on
|
|
# the variable group_concat_max_len, and
|
|
# convert_blob_length == max_len*collation->mbmaxlen > CONVERT_IF_BIGGER_TO_BLOB
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select group_concat(b1) from t2_1025 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select group_concat(b1) from t2_1025 group by b2);
|
|
|
|
set @@group_concat_max_len = 256; # anything < (CONVERT_IF_BIGGER_TO_BLOB = 1025)
|
|
|
|
explain extended select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select group_concat(b1) from t2_1025 group by b2);
|
|
|
|
select left(a1,7), left(a2,7)
|
|
from t1_1025
|
|
where a1 in (select group_concat(b1) from t2_1025 group by b2);
|
|
|
|
drop table t1_1025, t2_1025, t3_1025;
|
|
|
|
# test for BIT fields
|
|
create table t1bit (a1 bit(3), a2 bit(3));
|
|
create table t2bit (b1 bit(3), b2 bit(3));
|
|
|
|
insert into t1bit values (b'000', b'100');
|
|
insert into t1bit values (b'001', b'101');
|
|
insert into t1bit values (b'010', b'110');
|
|
|
|
insert into t2bit values (b'001', b'101');
|
|
insert into t2bit values (b'010', b'110');
|
|
insert into t2bit values (b'110', b'111');
|
|
|
|
set @@optimizer_switch='semijoin=off';
|
|
|
|
explain extended select bin(a1), bin(a2)
|
|
from t1bit
|
|
where (a1, a2) in (select b1, b2 from t2bit);
|
|
|
|
select bin(a1), bin(a2)
|
|
from t1bit
|
|
where (a1, a2) in (select b1, b2 from t2bit);
|
|
|
|
drop table t1bit, t2bit;
|
|
|
|
# test mixture of BIT and BLOB
|
|
create table t1bb (a1 bit(3), a2 blob(3));
|
|
create table t2bb (b1 bit(3), b2 blob(3));
|
|
|
|
insert into t1bb values (b'000', '100');
|
|
insert into t1bb values (b'001', '101');
|
|
insert into t1bb values (b'010', '110');
|
|
|
|
insert into t2bb values (b'001', '101');
|
|
insert into t2bb values (b'010', '110');
|
|
insert into t2bb values (b'110', '111');
|
|
|
|
explain extended select bin(a1), a2
|
|
from t1bb
|
|
where (a1, a2) in (select b1, b2 from t2bb);
|
|
|
|
select bin(a1), a2
|
|
from t1bb
|
|
where (a1, a2) in (select b1, b2 from t2bb);
|
|
|
|
drop table t1bb, t2bb;
|
|
drop table t1, t2, t3, t1i, t2i, t3i, columns;
|
|
|
|
/******************************************************************************
|
|
* Test the cache of the left operand of IN.
|
|
******************************************************************************/
|
|
set @@optimizer_switch='semijoin=off';
|
|
|
|
# Test that default values of Cached_item are not used for comparison
|
|
create table t1 (s1 int);
|
|
create table t2 (s2 int);
|
|
insert into t1 values (5),(1),(0);
|
|
insert into t2 values (0), (1);
|
|
select s2 from t2 where s2 in (select s1 from t1);
|
|
drop table t1, t2;
|
|
|
|
create table t1 (a int not null, b int not null);
|
|
create table t2 (c int not null, d int not null);
|
|
create table t3 (e int not null);
|
|
|
|
# the first outer row has no matching inner row
|
|
insert into t1 values (1,10);
|
|
insert into t1 values (1,20);
|
|
insert into t1 values (2,10);
|
|
insert into t1 values (2,20);
|
|
insert into t1 values (2,30);
|
|
insert into t1 values (3,20);
|
|
insert into t1 values (4,40);
|
|
|
|
insert into t2 values (2,10);
|
|
insert into t2 values (2,20);
|
|
insert into t2 values (2,40);
|
|
insert into t2 values (3,20);
|
|
insert into t2 values (4,10);
|
|
insert into t2 values (5,10);
|
|
|
|
insert into t3 values (10);
|
|
insert into t3 values (10);
|
|
insert into t3 values (20);
|
|
insert into t3 values (30);
|
|
|
|
explain extended
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
|
|
create index it1a on t1(a);
|
|
|
|
explain extended
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
|
|
# the first outer row has a matching inner row
|
|
insert into t2 values (1,10);
|
|
|
|
explain extended
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
select a from t1 where a in (select c from t2 where d >= 20);
|
|
|
|
# cacheing for IN predicates inside a having clause - here the cached
|
|
# items are changed to point to temporary tables.
|
|
explain extended
|
|
select a from t1 group by a having a in (select c from t2 where d >= 20);
|
|
select a from t1 group by a having a in (select c from t2 where d >= 20);
|
|
|
|
# create an index that can be used for the outer query GROUP BY
|
|
create index iab on t1(a, b);
|
|
explain extended
|
|
select a from t1 group by a having a in (select c from t2 where d >= 20);
|
|
select a from t1 group by a having a in (select c from t2 where d >= 20);
|
|
|
|
explain extended
|
|
select a from t1 group by a
|
|
having a in (select c from t2 where d >= some(select e from t3 where max(b)=e));
|
|
select a from t1 group by a
|
|
having a in (select c from t2 where d >= some(select e from t3 where max(b)=e));
|
|
explain extended
|
|
select a from t1
|
|
where a in (select c from t2 where d >= some(select e from t3 where b=e));
|
|
select a from t1
|
|
where a in (select c from t2 where d >= some(select e from t3 where b=e));
|
|
|
|
drop table t1, t2, t3;
|
|
|
|
#
|
|
# BUG#36133 "Assertion `exec_method != MATERIALIZATION || (exec_method == MATERIALIZATION &&"
|
|
#
|
|
create table t2 (a int, b int, key(a), key(b));
|
|
insert into t2 values (3,3),(3,3),(3,3);
|
|
select 1 from t2 where
|
|
t2.a > 1
|
|
or
|
|
t2.a = 3 and not t2.a not in (select t2.b from t2);
|
|
drop table t2;
|
|
|
|
#
|
|
# BUG#37896 Assertion on entry of Item_in_subselect::exec on subquery with AND NOT
|
|
#
|
|
create table t1 (a1 int key);
|
|
create table t2 (b1 int);
|
|
insert into t1 values (5);
|
|
|
|
# Query with group by, executed via materialization
|
|
explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1);
|
|
select min(a1) from t1 where 7 in (select b1 from t2 group by b1);
|
|
# Query with group by, executed via IN=>EXISTS
|
|
set @@optimizer_switch='default,materialization=off';
|
|
explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1);
|
|
select min(a1) from t1 where 7 in (select b1 from t2 group by b1);
|
|
|
|
# Executed with materialization
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
explain select min(a1) from t1 where 7 in (select b1 from t2);
|
|
select min(a1) from t1 where 7 in (select b1 from t2);
|
|
# Executed with semi-join. Notice, this time we get a different result (NULL).
|
|
# This is the only correct result of all four queries. This difference is
|
|
# filed as BUG#40037.
|
|
set @@optimizer_switch='default,materialization=off';
|
|
explain select min(a1) from t1 where 7 in (select b1 from t2);
|
|
select min(a1) from t1 where 7 in (select b1 from t2);
|
|
drop table t1,t2;
|
|
|
|
#
|
|
# BUG#36752 "subquery materialization produces wrong results when comparing different types"
|
|
#
|
|
create table t1 (a char(2), b varchar(10));
|
|
insert into t1 values ('a', 'aaa');
|
|
insert into t1 values ('aa', 'aaaa');
|
|
|
|
set @@optimizer_switch='default,semijoin=off';
|
|
explain select a,b from t1 where b in (select a from t1);
|
|
select a,b from t1 where b in (select a from t1);
|
|
prepare st1 from "select a,b from t1 where b in (select a from t1)";
|
|
execute st1;
|
|
execute st1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Bug #44303 Assertion failures in Field_new_decimal::store_decimal
|
|
# when executing materialized InsideOut semijoin
|
|
#
|
|
CREATE TABLE t1 (f1 INT, f2 DECIMAL(5,3)) ENGINE=MyISAM;
|
|
INSERT INTO t1 (f1, f2) VALUES (1, 1.789);
|
|
INSERT INTO t1 (f1, f2) VALUES (13, 1.454);
|
|
INSERT INTO t1 (f1, f2) VALUES (10, 1.668);
|
|
|
|
CREATE TABLE t2 LIKE t1;
|
|
INSERT INTO t2 VALUES (1, 1.789);
|
|
INSERT INTO t2 VALUES (13, 1.454);
|
|
|
|
SET @@optimizer_switch='default,semijoin=on,materialization=on';
|
|
EXPLAIN SELECT COUNT(*) FROM t1 WHERE (f1,f2) IN (SELECT f1,f2 FROM t2);
|
|
SELECT COUNT(*) FROM t1 WHERE (f1,f2) IN (SELECT f1,f2 FROM t2);
|
|
|
|
DROP TABLE t1, t2;
|
|
|
|
#
|
|
# BUG#46548 IN-subqueries return 0 rows with materialization=on
|
|
#
|
|
CREATE TABLE t1 (
|
|
pk int,
|
|
a varchar(1),
|
|
b varchar(4),
|
|
c varchar(4),
|
|
d varchar(4),
|
|
PRIMARY KEY (pk)
|
|
);
|
|
INSERT INTO t1 VALUES (1,'o','ffff','ffff','ffoo'),(2,'f','ffff','ffff','ffff');
|
|
|
|
CREATE TABLE t2 LIKE t1;
|
|
INSERT INTO t2 VALUES (1,'i','iiii','iiii','iiii'),(2,'f','ffff','ffff','ffff');
|
|
|
|
SET @@optimizer_switch='default,semijoin=on,materialization=on';
|
|
EXPLAIN SELECT pk FROM t1 WHERE (a) IN (SELECT a FROM t2 WHERE pk > 0);
|
|
SELECT pk FROM t1 WHERE (a) IN (SELECT a FROM t2 WHERE pk > 0);
|
|
SELECT pk FROM t1 WHERE (b,c,d) IN (SELECT b,c,d FROM t2 WHERE pk > 0);
|
|
DROP TABLE t1, t2;
|
|
|
|
--echo #
|
|
--echo # BUG#50019: Wrong result for IN-subquery with materialization
|
|
--echo #
|
|
create table t1(i int);
|
|
insert into t1 values (1), (2), (3), (4), (5), (6), (7), (8), (9), (10);
|
|
create table t2(i int);
|
|
insert into t2 values (1), (2), (3), (4), (5), (6), (7), (8), (9), (10);
|
|
create table t3(i int);
|
|
insert into t3 values (1), (2), (3), (4), (5), (6), (7), (8), (9), (10);
|
|
select * from t1 where t1.i in (select t2.i from t2 join t3 where t2.i + t3.i = 5);
|
|
set @save_optimizer_switch=@@optimizer_switch;
|
|
set session optimizer_switch='materialization=off';
|
|
select * from t1 where t1.i in (select t2.i from t2 join t3 where t2.i + t3.i = 5);
|
|
set session optimizer_switch=@save_optimizer_switch;
|
|
drop table t1, t2, t3;
|
|
|
|
#
|
|
# Test that the contents of the temp table of a materialized subquery is
|
|
# cleaned up between PS re-executions.
|
|
#
|
|
|
|
create table t0 (a int);
|
|
insert into t0 values (0),(1),(2);
|
|
create table t1 (a int);
|
|
insert into t1 values (0),(1),(2);
|
|
explain select a, a in (select a from t1) from t0;
|
|
select a, a in (select a from t1) from t0;
|
|
prepare s from 'select a, a in (select a from t1) from t0';
|
|
execute s;
|
|
update t1 set a=123;
|
|
execute s;
|
|
drop table t0, t1;
|
|
|
|
|
|
--echo #
|
|
--echo # LPBUG#609121: RQG: wrong result on aggregate + NOT IN + HAVING and
|
|
--echo # partial_match_table_scan=on
|
|
--echo #
|
|
|
|
create table t1 (c1 int);
|
|
create table t2 (c2 int);
|
|
insert into t1 values (1);
|
|
insert into t2 values (2);
|
|
|
|
set @@optimizer_switch='semijoin=off';
|
|
|
|
EXPLAIN
|
|
SELECT SUM(c1) c1_sum FROM t1 WHERE c1 IN (SELECT c2 FROM t2);
|
|
SELECT SUM(c1) c1_sum FROM t1 WHERE c1 IN (SELECT c2 FROM t2);
|
|
EXPLAIN
|
|
SELECT SUM(c1) c1_sum FROM t1 WHERE c1 IN (SELECT c2 FROM t2) HAVING c1_sum;
|
|
SELECT SUM(c1) c1_sum FROM t1 WHERE c1 IN (SELECT c2 FROM t2) HAVING c1_sum;
|
|
|
|
drop table t1, t2;
|