Skip to content

Commit

Permalink
Improve table pruning in optimizer with up to date key_dependent map
Browse files Browse the repository at this point in the history
Part of:
MDEV-28073 Slow query performance in MariaDB when using many tables

s->key_dependent has a list of tables that are compared with key fields
in the current table.  However it does not take into account if a key
field could be resolved by another table.
This is because MariaDB expands 'join_tab->keyuse' to include all generated
comparisons.
For example:
SELECT * from t1,t2,t3 where t1.key=t2.key and t2.key=t3.key
In this case keyuse for t1 includes t2.key and t3.key and key_dependent
contains 't2.map | t3.map'
If we in best_extension_by_limited_search() consider t2,t1 then t1's
key is fully defined, but we cannot do any prune of plans as
s->key_dependent indicates that t3 is still needed.

Fixed by calculating in best_access_patch the current key_dependent map
of tables that is needed to satisfy all keys. This allows us to prune
more bad plans earlier as soon as all keys can be used.

We also set key_dependent to 0 if we found an EQ_REF key, as this an
optimal key for the table and there is no reason to check more keys.
  • Loading branch information
montywi authored and spetrunia committed Jun 7, 2022
1 parent 64f24b7 commit 432a4eb
Show file tree
Hide file tree
Showing 6 changed files with 135 additions and 83 deletions.
135 changes: 68 additions & 67 deletions mysql-test/main/derived_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -9684,11 +9684,22 @@ EXPLAIN
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100,
"attached_condition": "1 in (0,dt1.a)",
"attached_condition": "1 in (0,t1.a) and t1.a is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
Expand All @@ -9706,18 +9717,6 @@ EXPLAIN
}
}
}
},
"block-nl-join": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100
},
"buffer_type": "flat",
"buffer_size": "65",
"join_type": "BNL",
"attached_condition": "t1.a = dt1.a"
}
}
}
Expand All @@ -9743,11 +9742,22 @@ EXPLAIN
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100,
"attached_condition": "dt.a in (1,dt.a)",
"attached_condition": "t1.a in (1,t1.a) and t1.a is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
Expand All @@ -9765,18 +9775,6 @@ EXPLAIN
}
}
}
},
"block-nl-join": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100
},
"buffer_type": "flat",
"buffer_size": "119",
"join_type": "BNL",
"attached_condition": "t1.a = dt.a"
}
}
}
Expand Down Expand Up @@ -10376,11 +10374,22 @@ EXPLAIN
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived3>",
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100,
"attached_condition": "t.f2 < 2",
"attached_condition": "t1.f2 < 2 and t1.f2 is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["f2"],
"ref": ["test.t1.f2"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
Expand All @@ -10393,13 +10402,6 @@ EXPLAIN
}
}
}
},
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100,
"attached_condition": "t1.f2 = t.f2"
}
}
}
Expand All @@ -10417,11 +10419,22 @@ EXPLAIN
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived3>",
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100,
"attached_condition": "t.f2 < 2",
"attached_condition": "t1.f2 < 2 and t1.f2 is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["f2"],
"ref": ["test.t1.f2"],
"rows": 1,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 3,
Expand All @@ -10436,18 +10449,6 @@ EXPLAIN
}
}
}
},
"block-nl-join": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 2,
"filtered": 100
},
"buffer_type": "flat",
"buffer_size": "65",
"join_type": "BNL",
"attached_condition": "t1.f2 = t.f2"
}
}
}
Expand Down Expand Up @@ -14388,8 +14389,8 @@ a b c a b c
3 21 500 3 21 231
explain select * from v1,t2 where (v1.b=t2.b) and (v1.a<4);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 Using where
1 PRIMARY t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join)
1 PRIMARY t2 ALL NULL NULL NULL NULL 9 Using where
1 PRIMARY <derived2> ref key0 key0 5 test.t2.b 2 Using where
2 DERIVED t3 range i1 i1 5 NULL 2 Using index condition
3 UNION t3 range i1 i1 5 NULL 1 Using index condition
NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL
Expand All @@ -14399,9 +14400,21 @@ EXPLAIN
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"table_name": "t2",
"access_type": "ALL",
"rows": 3,
"rows": 9,
"filtered": 100,
"attached_condition": "t2.b is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["b"],
"ref": ["test.t2.b"],
"rows": 2,
"filtered": 100,
"attached_condition": "v1.a < 4",
"materialized": {
Expand Down Expand Up @@ -14447,18 +14460,6 @@ EXPLAIN
}
}
}
},
"block-nl-join": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 9,
"filtered": 100
},
"buffer_type": "flat",
"buffer_size": "173",
"join_type": "BNL",
"attached_condition": "t2.b = v1.b"
}
}
}
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/main/join_nested.result
Original file line number Diff line number Diff line change
Expand Up @@ -1476,9 +1476,9 @@ join t5 on t5.a=t3.b) on t3.a=t2.b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 ALL NULL NULL NULL NULL X
1 SIMPLE t3 ref a a 5 test.t2.b X Using where
1 SIMPLE t5 ref a a 5 test.t3.b X
1 SIMPLE t4 ref a a 5 test.t5.a X Using where
1 SIMPLE t4 ref a a 5 test.t3.b X Using where
1 SIMPLE t6 ref a a 5 test.t4.b X
1 SIMPLE t5 ref a a 5 test.t3.b X
drop table t0, t1, t2, t3, t4, t5, t6, t7;
create table t1 (a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/main/join_nested_jcl6.result
Original file line number Diff line number Diff line change
Expand Up @@ -1485,9 +1485,9 @@ join t5 on t5.a=t3.b) on t3.a=t2.b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 ALL NULL NULL NULL NULL X
1 SIMPLE t3 ref a a 5 test.t2.b X Using where; Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
1 SIMPLE t5 ref a a 5 test.t3.b X Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
1 SIMPLE t4 ref a a 5 test.t5.a X Using where; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
1 SIMPLE t4 ref a a 5 test.t3.b X Using where; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
1 SIMPLE t6 ref a a 5 test.t4.b X Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
1 SIMPLE t5 ref a a 5 test.t3.b X Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
drop table t0, t1, t2, t3, t4, t5, t6, t7;
create table t1 (a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/main/selectivity_innodb.result
Original file line number Diff line number Diff line change
Expand Up @@ -331,8 +331,8 @@ group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice
order by o_totalprice desc, o_orderdate;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00
1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00
1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index
2 MATERIALIZED lineitem index NULL PRIMARY 8 NULL 6005 100.00
Warnings:
Expand Down Expand Up @@ -365,8 +365,8 @@ group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice
order by o_totalprice desc, o_orderdate;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY orders ALL PRIMARY,i_o_custkey NULL NULL NULL 1500 100.00 Using where; Using temporary; Using filesort
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00
1 PRIMARY customer eq_ref PRIMARY PRIMARY 4 dbt3_s001.orders.o_custkey 1 100.00
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 dbt3_s001.orders.o_orderkey 1 100.00
1 PRIMARY lineitem ref PRIMARY,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey_quantity 4 dbt3_s001.orders.o_orderkey 4 100.00 Using index
2 MATERIALIZED lineitem index NULL PRIMARY 8 NULL 6005 100.00
Warnings:
Expand Down
Loading

0 comments on commit 432a4eb

Please sign in to comment.