Skip to content

Commit

Permalink
Fixed the bug mdev-12845.
Browse files Browse the repository at this point in the history
This patch fills in a serious flaw in the
code that supports condition pushdown into
materialized views / derived tables.

If a predicate happened to contain a reference
to a mergeable view / derived table and it does
not depended directly on the target materialized
view / derived table then the predicate was not
considered as a subject to pusdown to this view
/ derived table.
  • Loading branch information
igorbabaev committed Jun 23, 2017
1 parent a8131e7 commit 9f36221
Show file tree
Hide file tree
Showing 13 changed files with 568 additions and 147 deletions.
2 changes: 1 addition & 1 deletion mysql-test/r/derived.result
Original file line number Diff line number Diff line change
Expand Up @@ -554,7 +554,7 @@ EXPLAIN SELECT * FROM (SELECT * FROM t1) AS table1,
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 system NULL NULL NULL NULL 1
1 PRIMARY <derived3> ref key0 key0 5 const 0
3 DERIVED t2 ALL NULL NULL NULL NULL 2 Using temporary
3 DERIVED t2 ALL NULL NULL NULL NULL 2 Using where; Using temporary
Warnings:
Note 1249 Select 4 was reduced during optimization
DROP TABLE t1, t2;
Expand Down
229 changes: 227 additions & 2 deletions mysql-test/r/derived_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -7234,6 +7234,7 @@ EXPLAIN
"materialized": {
"query_block": {
"select_id": 5,
"having_condition": "s > 2",
"filesort": {
"sort_key": "t4.d",
"temporary_table": {
Expand Down Expand Up @@ -7605,6 +7606,7 @@ EXPLAIN
"materialized": {
"query_block": {
"select_id": 3,
"having_condition": "s < 50",
"filesort": {
"sort_key": "t3.a",
"temporary_table": {
Expand Down Expand Up @@ -7755,9 +7757,14 @@ EXPLAIN
"select_id": 4,
"table": {
"table_name": "t",
"access_type": "ALL",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["pk"],
"rows": 2,
"filtered": 100
"filtered": 100,
"index_condition": "t.pk > 2"
}
}
}
Expand Down Expand Up @@ -8447,3 +8454,221 @@ WHERE row <> order_number;
row order_number
14 51
DROP TABLE sales_documents;
#
# MDEV-12845: pushdown from merged derived using equalities
#
create table t1 (a int);
insert into t1 values
(4), (8), (5), (3), (10), (2), (7);
create table t2 (b int, c int);
insert into t2 values
(2,1), (5,2), (2,2), (4,1), (4,3),
(5,3), (2,4), (4,6), (2,1);
create view v1 as
select b, sum(c) as s from t2 group by b;
create view v2 as
select distinct b, c from t2;
create view v3 as
select b, max(c) as m from t2 group by b;
select b
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where b > 2;
b
4
5
explain format=json select b
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where b > 2;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a > 2 and t1.a is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["b"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
"filesort": {
"sort_key": "t2.b",
"temporary_table": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 9,
"filtered": 100,
"attached_condition": "t2.b > 2"
}
}
}
}
}
}
}
}
select a
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where a > 2;
a
4
5
explain format=json select a
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where a > 2;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a > 2 and t1.a is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["b"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
"filesort": {
"sort_key": "t2.b",
"temporary_table": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 9,
"filtered": 100,
"attached_condition": "t2.b > 2"
}
}
}
}
}
}
}
}
select a
from ( select t1.a, v2.b, v2.c from t1, v2 where t1.a = v2.b ) as t
where a > 2;
a
4
4
4
5
5
explain format=json select a
from ( select t1.a, v2.b, v2.c from t1, v2 where t1.a = v2.b ) as t
where a > 2;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a > 2 and t1.a is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["b"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
"temporary_table": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 9,
"filtered": 100,
"attached_condition": "t2.b > 2"
}
}
}
}
}
}
}
select a
from ( select t1.a, v3.b, v3.m from t1, v3 where t1.a = v3.m ) as t
where a > 2;
a
4
3
explain format=json select a
from ( select t1.a, v3.b, v3.m from t1, v3 where t1.a = v3.m ) as t
where a > 2;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a > 2 and t1.a is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["m"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
"having_condition": "m > 2",
"filesort": {
"sort_key": "t2.b",
"temporary_table": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 9,
"filtered": 100
}
}
}
}
}
}
}
}
drop view v1,v2,v3;
drop table t1,t2;
4 changes: 2 additions & 2 deletions mysql-test/r/derived_view.result
Original file line number Diff line number Diff line change
Expand Up @@ -900,7 +900,7 @@ EXPLAIN
"access_type": "ALL",
"rows": 11,
"filtered": 100,
"attached_condition": "t1.f1 in (2,3)"
"attached_condition": "t1.f1 < 7 and t1.f1 in (2,3)"
}
}
}
Expand Down Expand Up @@ -1107,7 +1107,7 @@ id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 system NULL NULL NULL NULL 1
1 PRIMARY t2 ref a a 4 const 1 Using index
1 PRIMARY <derived2> ref key0 key0 8 const,const 1
2 DERIVED t3 ALL NULL NULL NULL NULL 12 Using temporary; Using filesort
2 DERIVED t3 ALL NULL NULL NULL NULL 12 Using where; Using temporary; Using filesort
SELECT * FROM t1, t2, v1 WHERE t2.a=t1.a AND t2.a=v1.a AND t2.a=v1.b;
a a a b
c c c c
Expand Down
57 changes: 57 additions & 0 deletions mysql-test/t/derived_cond_pushdown.test
Original file line number Diff line number Diff line change
Expand Up @@ -1452,3 +1452,60 @@ SELECT * FROM
WHERE row <> order_number;

DROP TABLE sales_documents;

--echo #
--echo # MDEV-12845: pushdown from merged derived using equalities
--echo #

create table t1 (a int);
insert into t1 values
(4), (8), (5), (3), (10), (2), (7);

create table t2 (b int, c int);
insert into t2 values
(2,1), (5,2), (2,2), (4,1), (4,3),
(5,3), (2,4), (4,6), (2,1);

create view v1 as
select b, sum(c) as s from t2 group by b;

create view v2 as
select distinct b, c from t2;

create view v3 as
select b, max(c) as m from t2 group by b;

let $q1=
select b
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where b > 2;

eval $q1;
eval explain format=json $q1;

let $q2=
select a
from ( select t1.a, v1.b, v1.s from t1, v1 where t1.a = v1.b ) as t
where a > 2;

eval $q2;
eval explain format=json $q2;

let $q3=
select a
from ( select t1.a, v2.b, v2.c from t1, v2 where t1.a = v2.b ) as t
where a > 2;

eval $q3;
eval explain format=json $q3;

let $q4=
select a
from ( select t1.a, v3.b, v3.m from t1, v3 where t1.a = v3.m ) as t
where a > 2;

eval $q4;
eval explain format=json $q4;

drop view v1,v2,v3;
drop table t1,t2;
Loading

0 comments on commit 9f36221

Please sign in to comment.