Commit 9cea4ccf authored by Igor Babaev's avatar Igor Babaev

MDEV-16726 Assertion `tab->type == JT_REF || tab->type == JT_EQ_REF' failed

Due to a legacy bug in the code of make_join_statistics() detecting
so-called constant tables could miss some of them in rare queries
that used RIGHT JOIN. As a result these queries had execution plans
different from the execution plans of the equivalent queries with
LEFT JOIN.
Besides starting from 10.2 this could trigger an assertion failure.
parent 8c45eb3e
...@@ -2368,5 +2368,55 @@ id sid id ...@@ -2368,5 +2368,55 @@ id sid id
1 NULL NULL 1 NULL NULL
2 NULL NULL 2 NULL NULL
drop table t1, t2; drop table t1, t2;
#
# MDEV-16726: SELECT with STRAGHT JOIN containing NESTED RIGHT JOIN
# converted to INNER JOIN with first constant inner table
#
CREATE TABLE t1 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1), KEY v1 (v1,i1)
) engine=MyISAM;
INSERT INTO t1 VALUES
(8,3,'c','c'),(9,4,'z','z'),(10,3,'i','i'),(11,186,'x','x'),
(14,226,'m','m'),(15,133,'p','p');
CREATE TABLE t2 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1)
) engine=MyISAM;
INSERT INTO t2 VALUES (10,6,'p','p');
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
Warnings:
Note 1003 select straight_join 'p' AS `v2` from `test`.`t1` join `test`.`t1` `tb1` left join `test`.`t1` `tb2` on(multiple equal(`test`.`tb2`.`v1`, NULL)) where 0 order by NULL
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t2,t1)
LEFT JOIN
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
Warnings:
Note 1003 select straight_join 'p' AS `v2` from `test`.`t1` join `test`.`t1` `tb1` left join `test`.`t1` `tb2` on(multiple equal(`test`.`tb2`.`v1`, NULL)) where 0 order by NULL
SELECT STRAIGHT_JOIN DISTINCT t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
v2
DROP TABLE t1,t2;
# end of 5.5 tests # end of 5.5 tests
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
...@@ -2379,6 +2379,56 @@ id sid id ...@@ -2379,6 +2379,56 @@ id sid id
1 NULL NULL 1 NULL NULL
2 NULL NULL 2 NULL NULL
drop table t1, t2; drop table t1, t2;
#
# MDEV-16726: SELECT with STRAGHT JOIN containing NESTED RIGHT JOIN
# converted to INNER JOIN with first constant inner table
#
CREATE TABLE t1 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1), KEY v1 (v1,i1)
) engine=MyISAM;
INSERT INTO t1 VALUES
(8,3,'c','c'),(9,4,'z','z'),(10,3,'i','i'),(11,186,'x','x'),
(14,226,'m','m'),(15,133,'p','p');
CREATE TABLE t2 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1)
) engine=MyISAM;
INSERT INTO t2 VALUES (10,6,'p','p');
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
Warnings:
Note 1003 select straight_join 'p' AS `v2` from `test`.`t1` join `test`.`t1` `tb1` left join `test`.`t1` `tb2` on(multiple equal(`test`.`tb2`.`v1`, NULL)) where 0 order by NULL
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t2,t1)
LEFT JOIN
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
Warnings:
Note 1003 select straight_join 'p' AS `v2` from `test`.`t1` join `test`.`t1` `tb1` left join `test`.`t1` `tb2` on(multiple equal(`test`.`tb2`.`v1`, NULL)) where 0 order by NULL
SELECT STRAIGHT_JOIN DISTINCT t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
v2
DROP TABLE t1,t2;
# end of 5.5 tests # end of 5.5 tests
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
set join_cache_level=default; set join_cache_level=default;
......
...@@ -442,7 +442,7 @@ SELECT i2 FROM t2 RIGHT JOIN t3 ON (c3 = c2) WHERE pk3 = i1 ...@@ -442,7 +442,7 @@ SELECT i2 FROM t2 RIGHT JOIN t3 ON (c3 = c2) WHERE pk3 = i1
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 system NULL NULL NULL NULL 1 1 PRIMARY t1 system NULL NULL NULL NULL 1
2 DEPENDENT SUBQUERY t3 const PRIMARY PRIMARY 4 const 1 2 DEPENDENT SUBQUERY t3 const PRIMARY PRIMARY 4 const 1
2 DEPENDENT SUBQUERY t2 index NULL i2 11 NULL 2 Using where; Using index 2 DEPENDENT SUBQUERY t2 index i2 i2 11 NULL 2 Using where; Using index
DROP TABLE t1,t2,t3; DROP TABLE t1,t2,t3;
# #
# MDEV-7599: in-to-exists chosen after min/max optimization # MDEV-7599: in-to-exists chosen after min/max optimization
......
...@@ -1911,6 +1911,54 @@ select * from t1 t ...@@ -1911,6 +1911,54 @@ select * from t1 t
on t.id=r.id ; on t.id=r.id ;
drop table t1, t2; drop table t1, t2;
--echo #
--echo # MDEV-16726: SELECT with STRAGHT JOIN containing NESTED RIGHT JOIN
--echo # converted to INNER JOIN with first constant inner table
--echo #
CREATE TABLE t1 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1), KEY v1 (v1,i1)
) engine=MyISAM;
INSERT INTO t1 VALUES
(8,3,'c','c'),(9,4,'z','z'),(10,3,'i','i'),(11,186,'x','x'),
(14,226,'m','m'),(15,133,'p','p');
CREATE TABLE t2 (
pk int PRIMARY KEY, i1 int, v1 varchar(1), v2 varchar(1)
) engine=MyISAM;
INSERT INTO t2 VALUES (10,6,'p','p');
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
EXPLAIN EXTENDED
SELECT STRAIGHT_JOIN t2.v2
FROM
(t2,t1)
LEFT JOIN
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
SELECT STRAIGHT_JOIN DISTINCT t2.v2
FROM
(t1 as tb1 LEFT JOIN t1 AS tb2 ON tb2.v1 = tb1.v2)
RIGHT JOIN
(t2,t1)
ON t1.pk = t2.pk AND t2.v2 = tb1.v1
WHERE tb1.pk = 40
ORDER BY tb1.i1;
DROP TABLE t1,t2;
--echo # end of 5.5 tests --echo # end of 5.5 tests
SET optimizer_switch=@save_optimizer_switch; SET optimizer_switch=@save_optimizer_switch;
...@@ -3456,8 +3456,8 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list, ...@@ -3456,8 +3456,8 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list,
int ref_changed; int ref_changed;
do do
{ {
more_const_tables_found:
ref_changed = 0; ref_changed = 0;
more_const_tables_found:
found_ref=0; found_ref=0;
/* /*
...@@ -3622,7 +3622,7 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list, ...@@ -3622,7 +3622,7 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list,
} }
} }
} }
} while (join->const_table_map & found_ref && ref_changed); } while (ref_changed);
join->sort_by_table= get_sort_by_table(join->order, join->group_list, join->sort_by_table= get_sort_by_table(join->order, join->group_list,
join->select_lex->leaf_tables, join->select_lex->leaf_tables,
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment