Skip to content

Commit b6719c9

Browse files
author
Ajo Robert
committed
Bug#36918913 INCORRECT QUERY RESULT FOR INDEX_SUBQUERY TYPE
IN NULL SUBQUERY The filter condition in the subquery was getting ignored when a query uses indexsubquery-engine for subquery execution and the subquery table uses materialization in the plan. The derived table access path was replacing the filter condition resulting a final plan without the filter layer. Updated the code to add derived table access path along with the filter access path instead of replacing. Change-Id: I26b14f033c35fb8aa2cafab2c9dec5dda2070baa
1 parent f5a4ff1 commit b6719c9

File tree

4 files changed

+65
-9
lines changed

4 files changed

+65
-9
lines changed

mysql-test/r/condition_filter.result

Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -105,3 +105,37 @@ OK
105105
1
106106
SET optimizer_trace="enabled=off";
107107
DROP TABLE t1, t2;
108+
#
109+
# Bug#36918913 INCORRECT QUERY RESULT FOR INDEX_SUBQUERY TYPE IN NULL
110+
# SUBQUERY
111+
#
112+
SET @save_optimizer_switch= @@optimizer_switch;
113+
SET @@optimizer_switch= 'semijoin=off';
114+
CREATE TABLE t1 (a INT);
115+
INSERT INTO t1 VALUES (1), (2), (3);
116+
CREATE TABLE t2 (b INT);
117+
INSERT INTO t2 VALUES (1), (2), (3);
118+
ANALYZE TABLE t1, t2;
119+
Table Op Msg_type Msg_text
120+
test.t1 analyze status OK
121+
test.t2 analyze status OK
122+
SELECT * FROM t1 WHERE a IN (SELECT * FROM (
123+
SELECT b FROM t2 ORDER BY b LIMIT 2) x where b > 1);
124+
a
125+
2
126+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE a IN (SELECT * FROM (
127+
SELECT b FROM t2 ORDER BY b LIMIT 2) x where b > 1);
128+
EXPLAIN
129+
-> Filter: <in_optimizer>(t1.a,<exists>(select #2)) (rows=3)
130+
-> Table scan on t1 (rows=3)
131+
-> Select #2 (subquery in condition; dependent)
132+
-> Limit: 1 row(s) (rows=1)
133+
-> Filter: (x.b > 1) (rows=2)
134+
-> Covering index lookup on x using <auto_key0> (b=<cache>(t1.a)) (rows=2)
135+
-> Materialize (rows=2)
136+
-> Limit: 2 row(s) (rows=2)
137+
-> Sort: t2.b, limit input to 2 row(s) per chunk (rows=3)
138+
-> Table scan on t2 (rows=3)
139+
140+
DROP TABLE t1,t2;
141+
SET @@optimizer_switch= @save_optimizer_switch;

mysql-test/r/explain_tree.result

Lines changed: 8 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -868,13 +868,14 @@ EXPLAIN
868868
-> Group (no aggregates) (cost=0.45 rows=1)
869869
-> Table scan on t1 (cost=0.35 rows=1)
870870
-> Select #2 (subquery in projection; dependent)
871-
-> Limit: 1 row(s) (cost=1.85..1.85 rows=1)
872-
-> Filter: <if>(outer_field_is_not_null, <is_not_null_test>(d.a), true) (cost=1.85..1.85 rows=1)
873-
-> Alternative plans for IN subquery: Index lookup unless a IS NULL (cost=0.8..1.85 rows=4)
874-
-> Covering index lookup on d using <auto_key0> (a=<cache>(t1.a) or NULL) (cost=1.4 rows=4)
875-
-> Materialize (cost=0.45..0.45 rows=1)
876-
-> Table scan on t1 (cost=0.35 rows=1)
877-
-> Table scan on d (cost=2.52 rows=2)
871+
-> Limit: 1 row(s) (cost=1.95..1.95 rows=1)
872+
-> Filter: <if>(outer_field_is_not_null, <is_not_null_test>(d.a), true) (cost=1.95..1.95 rows=1)
873+
-> Filter: <if>(outer_field_is_not_null, ((<cache>(t1.a) = d.a) or (d.a is null)), true) (cost=1.95..1.95 rows=1)
874+
-> Alternative plans for IN subquery: Index lookup unless a IS NULL (cost=0.8..1.85 rows=4)
875+
-> Covering index lookup on d using <auto_key0> (a=<cache>(t1.a) or NULL) (cost=1.4 rows=4)
876+
-> Materialize (cost=0.45..0.45 rows=1)
877+
-> Table scan on t1 (cost=0.35 rows=1)
878+
-> Table scan on d (cost=2.52 rows=2)
878879

879880
Warnings:
880881
Warning 1287 Setting user variables within expressions is deprecated and will be removed in a future release. Consider alternatives: 'SET variable=expression, ...', or 'SELECT expression(s) INTO variables(s)'.

mysql-test/t/condition_filter.test

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,5 @@
1+
--source include/elide_costs.inc
2+
13
--echo #
24
--echo # Bug 20219846: EXPLAIN FOR LIMIT QUERY SHOWS FILESORT BUT EXECUTION
35
--echo # IS DONE WITH INDEX ONLY
@@ -81,3 +83,23 @@ SELECT TRACE NOT RLIKE '"final_filtering_effect": 1' AS OK
8183
SET optimizer_trace="enabled=off";
8284

8385
DROP TABLE t1, t2;
86+
87+
--echo #
88+
--echo # Bug#36918913 INCORRECT QUERY RESULT FOR INDEX_SUBQUERY TYPE IN NULL
89+
--echo # SUBQUERY
90+
--echo #
91+
SET @save_optimizer_switch= @@optimizer_switch;
92+
SET @@optimizer_switch= 'semijoin=off';
93+
CREATE TABLE t1 (a INT);
94+
INSERT INTO t1 VALUES (1), (2), (3);
95+
CREATE TABLE t2 (b INT);
96+
INSERT INTO t2 VALUES (1), (2), (3);
97+
ANALYZE TABLE t1, t2;
98+
SELECT * FROM t1 WHERE a IN (SELECT * FROM (
99+
SELECT b FROM t2 ORDER BY b LIMIT 2) x where b > 1);
100+
--skip_if_hypergraph # Depends on the query plan.
101+
--replace_regex $elide_costs
102+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE a IN (SELECT * FROM (
103+
SELECT b FROM t2 ORDER BY b LIMIT 2) x where b > 1);
104+
DROP TABLE t1,t2;
105+
SET @@optimizer_switch= @save_optimizer_switch;

sql/sql_executor.cc

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -3405,8 +3405,7 @@ void JOIN::create_access_paths_for_index_subquery() {
34053405
path = NewMaterializedTableFunctionAccessPath(thd, first_qep_tab->table(),
34063406
tl->table_function, path);
34073407
} else {
3408-
path = GetAccessPathForDerivedTable(thd, first_qep_tab,
3409-
first_qep_tab->access_path());
3408+
path = GetAccessPathForDerivedTable(thd, first_qep_tab, path);
34103409
}
34113410
}
34123411

0 commit comments

Comments
 (0)