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.
This commit is contained in:
Sergei Petrunia 2025-04-14 16:49:25 +03:00
parent 7b0820b8b7
commit 8c7c144f19
3 changed files with 57 additions and 0 deletions

View File

@ -3611,3 +3611,32 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 100 Using where
1 SIMPLE t2 ref kp1 kp1 5 test.t1.a 1 Using index condition
drop table t1,t2;
#
# MDEV-36592: If the join_condition is specified via USING (column_list), the query plan depends ...
#
CREATE TABLE t1 (
id int(11),
f1 char(255),
PRIMARY KEY (id)
);
INSERT INTO t1 (id) VALUES (1),(2),(3);
UPDATE t1 SET f1=REPEAT('a',250);
CREATE TABLE t2 (id int(11), f2 INT NOT NULL);
INSERT INTO t2 select seq, seq from seq_1_to_20;
ANALYZE TABLE t1, t2;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
test.t2 analyze status Engine-independent statistics collected
test.t2 analyze status OK
# In both queries, t1 should use type=index, not type=ALL:
EXPLAIN SELECT count(*) FROM t2 JOIN t1 USING (id);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 3 Using index
1 SIMPLE t2 ALL NULL NULL NULL NULL 20 Using where; Using join buffer (flat, BNL join)
EXPLAIN SELECT count(*) FROM t1 JOIN t2 USING (id);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 3 Using index
1 SIMPLE t2 ALL NULL NULL NULL NULL 20 Using where; Using join buffer (flat, BNL join)
DROP TABLE t1,t2;
# End of 10.11 tests

View File

@ -2015,3 +2015,28 @@ where
t2.kp1=t1.a and t2.kp1<=100 and t2.kp2<=20;
drop table t1,t2;
--echo #
--echo # MDEV-36592: If the join_condition is specified via USING (column_list), the query plan depends ...
--echo #
CREATE TABLE t1 (
id int(11),
f1 char(255),
PRIMARY KEY (id)
);
INSERT INTO t1 (id) VALUES (1),(2),(3);
UPDATE t1 SET f1=REPEAT('a',250);
CREATE TABLE t2 (id int(11), f2 INT NOT NULL);
INSERT INTO t2 select seq, seq from seq_1_to_20;
ANALYZE TABLE t1, t2;
--echo # In both queries, t1 should use type=index, not type=ALL:
EXPLAIN SELECT count(*) FROM t2 JOIN t1 USING (id);
EXPLAIN SELECT count(*) FROM t1 JOIN t2 USING (id);
DROP TABLE t1,t2;
--echo # End of 10.11 tests

View File

@ -7414,6 +7414,9 @@ mark_common_columns(THD *thd, TABLE_LIST *table_ref_1, TABLE_LIST *table_ref_2,
if (!found)
continue; // No matching field
/* Restore field_2 to point to the field which was a match for field_1. */
field_2= nj_col_2->field();
/*
field_1 and field_2 have the same names. Check if they are in the USING
clause (if present), mark them as common fields, and add a new