Skip to content

Commit 8c7c144

Browse files
committed
MDEV-36592: In JOIN ... USING(columns), query plan depends on join order
"t1 JOIN t2 USING(col1,...)" calls mark_common_columns() to mark the listed columns as used in both used tables, t1 and t2. Due to a typo bug, it would mark the wrong column in the second table (t2): instead of t2.col1 it would mark the last column in t2. The harmful effects included JOIN_TAB(t2)->covering_keys not being set correctly. This changed the cost to access the table and then caused different query plans depending on which table was the second in the JOIN ... USING syntax.
1 parent 7b0820b commit 8c7c144

File tree

3 files changed

+57
-0
lines changed

3 files changed

+57
-0
lines changed

mysql-test/main/join.result

+29
Original file line numberDiff line numberDiff line change
@@ -3611,3 +3611,32 @@ id select_type table type possible_keys key key_len ref rows Extra
36113611
1 SIMPLE t1 ALL NULL NULL NULL NULL 100 Using where
36123612
1 SIMPLE t2 ref kp1 kp1 5 test.t1.a 1 Using index condition
36133613
drop table t1,t2;
3614+
#
3615+
# MDEV-36592: If the join_condition is specified via USING (column_list), the query plan depends ...
3616+
#
3617+
CREATE TABLE t1 (
3618+
id int(11),
3619+
f1 char(255),
3620+
PRIMARY KEY (id)
3621+
);
3622+
INSERT INTO t1 (id) VALUES (1),(2),(3);
3623+
UPDATE t1 SET f1=REPEAT('a',250);
3624+
CREATE TABLE t2 (id int(11), f2 INT NOT NULL);
3625+
INSERT INTO t2 select seq, seq from seq_1_to_20;
3626+
ANALYZE TABLE t1, t2;
3627+
Table Op Msg_type Msg_text
3628+
test.t1 analyze status Engine-independent statistics collected
3629+
test.t1 analyze status OK
3630+
test.t2 analyze status Engine-independent statistics collected
3631+
test.t2 analyze status OK
3632+
# In both queries, t1 should use type=index, not type=ALL:
3633+
EXPLAIN SELECT count(*) FROM t2 JOIN t1 USING (id);
3634+
id select_type table type possible_keys key key_len ref rows Extra
3635+
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 3 Using index
3636+
1 SIMPLE t2 ALL NULL NULL NULL NULL 20 Using where; Using join buffer (flat, BNL join)
3637+
EXPLAIN SELECT count(*) FROM t1 JOIN t2 USING (id);
3638+
id select_type table type possible_keys key key_len ref rows Extra
3639+
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 3 Using index
3640+
1 SIMPLE t2 ALL NULL NULL NULL NULL 20 Using where; Using join buffer (flat, BNL join)
3641+
DROP TABLE t1,t2;
3642+
# End of 10.11 tests

mysql-test/main/join.test

+25
Original file line numberDiff line numberDiff line change
@@ -2015,3 +2015,28 @@ where
20152015
t2.kp1=t1.a and t2.kp1<=100 and t2.kp2<=20;
20162016

20172017
drop table t1,t2;
2018+
2019+
--echo #
2020+
--echo # MDEV-36592: If the join_condition is specified via USING (column_list), the query plan depends ...
2021+
--echo #
2022+
CREATE TABLE t1 (
2023+
id int(11),
2024+
f1 char(255),
2025+
PRIMARY KEY (id)
2026+
);
2027+
INSERT INTO t1 (id) VALUES (1),(2),(3);
2028+
UPDATE t1 SET f1=REPEAT('a',250);
2029+
2030+
CREATE TABLE t2 (id int(11), f2 INT NOT NULL);
2031+
INSERT INTO t2 select seq, seq from seq_1_to_20;
2032+
2033+
ANALYZE TABLE t1, t2;
2034+
2035+
--echo # In both queries, t1 should use type=index, not type=ALL:
2036+
EXPLAIN SELECT count(*) FROM t2 JOIN t1 USING (id);
2037+
EXPLAIN SELECT count(*) FROM t1 JOIN t2 USING (id);
2038+
2039+
DROP TABLE t1,t2;
2040+
2041+
--echo # End of 10.11 tests
2042+

sql/sql_base.cc

+3
Original file line numberDiff line numberDiff line change
@@ -7414,6 +7414,9 @@ mark_common_columns(THD *thd, TABLE_LIST *table_ref_1, TABLE_LIST *table_ref_2,
74147414
if (!found)
74157415
continue; // No matching field
74167416

7417+
/* Restore field_2 to point to the field which was a match for field_1. */
7418+
field_2= nj_col_2->field();
7419+
74177420
/*
74187421
field_1 and field_2 have the same names. Check if they are in the USING
74197422
clause (if present), mark them as common fields, and add a new

0 commit comments

Comments
 (0)