1
0
mirror of https://github.com/mariadb-corporation/mariadb-columnstore-engine.git synced 2025-07-29 08:21:15 +03:00

MCOL-4493 Add ON expressions for WHERE processing when the JOIN

type is not LEFT/RIGHT.

In buildOuterJoin(), do not add ON expressions for WHERE
processing when the JOIN type is not LEFT/RIGHT.

Test cases to check correct processing of INNER JOIN ON expressions
with possible/impossible WHERE conditions are added for
  1. One side of the LEFT JOIN being INNER JOIN.
  2. One side of the LEFT JOIN being an INNER JOIN inside an INNER JOIN.
  3. Both sides of the LEFT JOIN being an INNER JOIN.
This commit is contained in:
Gagan Goel
2021-01-27 09:34:17 -05:00
parent 7277299628
commit abf45bf46c
3 changed files with 266 additions and 2 deletions

View File

@ -1320,7 +1320,7 @@ uint32_t buildOuterJoin(gp_walk_info& gwi, SELECT_LEX& select_lex)
(table_ptr->alias.length ? table_ptr->alias.str : ""), (table_ptr->alias.length ? table_ptr->alias.str : ""),
getViewName(table_ptr), true, lower_case_table_names); getViewName(table_ptr), true, lower_case_table_names);
if (table_ptr->outer_join && table_ptr->on_expr) if ((table_ptr->outer_join & (JOIN_TYPE_LEFT | JOIN_TYPE_RIGHT)) && table_ptr->on_expr)
{ {
// inner tables block // inner tables block
Item_cond* expr = reinterpret_cast<Item_cond*>(table_ptr->on_expr); Item_cond* expr = reinterpret_cast<Item_cond*>(table_ptr->on_expr);
@ -6297,7 +6297,7 @@ int processFrom(bool &isUnion,
} }
// Save on_expr to use it for WHERE processing // Save on_expr to use it for WHERE processing
if (!table_ptr->outer_join && table_ptr->on_expr) if (!(table_ptr->outer_join & (JOIN_TYPE_LEFT | JOIN_TYPE_RIGHT)) && table_ptr->on_expr)
{ {
on_expr_list.push_back(table_ptr->on_expr); on_expr_list.push_back(table_ptr->on_expr);
} }

View File

@ -0,0 +1,132 @@
DROP DATABASE IF EXISTS mcol_4493;
CREATE DATABASE mcol_4493;
USE mcol_4493;
CREATE TABLE t1 (a CHAR(10), b INT) ENGINE=columnstore;
INSERT INTO t1 VALUES ('a', 1), ('b', 2), ('c', 3);
CREATE TABLE t2 (a INT) ENGINE=columnstore;
INSERT INTO t2 values (2), (3);
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h
ON t1.b=_h.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 NULL
c 3 NULL
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=2) _h
ON t1.b=_h.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 2
c 3 NULL
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=3) _h
ON t1.b=_h.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 NULL
c 3 3
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON t1.b=_h.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 2
c 3 3
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 NULL
c 3 NULL
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=2) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 2
c 3 NULL
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=3) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 NULL
c 3 3
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
a b a
a 1 NULL
b 2 2
c 3 3
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
b 2 2
c 3 3
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND table1.b=2) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=2)) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
b 2 2
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND (table1.b=2 OR table1.b=1)) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=3)) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
b 2 NULL
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND table1.b=1) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
b 2 NULL
c 3 NULL
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=2)) _h
ON _g.b=_h.a ORDER BY _g.a;
a b a
b 2 2
c 3 NULL
DROP DATABASE mcol_4493;

132
mtr/bugfixes/mcol-4493.test Normal file
View File

@ -0,0 +1,132 @@
# Test case for MCOL-4493
# This test case demonstrates that the WHERE condition
# used in the ON expression of an INNER JOIN used in a
# subquery as the LEFT side of an outer join is getting
# processed correctly.
-- source ../include/have_columnstore.inc
-- disable_warnings
DROP DATABASE IF EXISTS mcol_4493;
-- enable_warnings
CREATE DATABASE mcol_4493;
USE mcol_4493;
CREATE TABLE t1 (a CHAR(10), b INT) ENGINE=columnstore;
INSERT INTO t1 VALUES ('a', 1), ('b', 2), ('c', 3);
CREATE TABLE t2 (a INT) ENGINE=columnstore;
INSERT INTO t2 values (2), (3);
# Test single INNER JOIN
## Test impossible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h
ON t1.b=_h.a ORDER BY t1.a;
## Test possible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=2) _h
ON t1.b=_h.a ORDER BY t1.a;
## Test possible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=3) _h
ON t1.b=_h.a ORDER BY t1.a;
## Test the INNER JOIN without a WHERE condition
SELECT * FROM t1 LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON t1.b=_h.a ORDER BY t1.a;
# Test nested INNER JOIN
## Test impossible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
## Test possible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=2) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
## Test possible WHERE condition in the ON expression
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=3) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
## Test the INNER JOIN without a WHERE condition
SELECT * FROM t1 LEFT JOIN
(SELECT table3.a FROM t2 table3 INNER JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h ON table3.a=_h.a) _g
ON t1.b=_g.a ORDER BY t1.a;
# Test INNER JOIN as both LEFT and RIGHT side of outer LEFT JOIN
## Without a WHERE condition
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON _g.b=_h.a ORDER BY _g.a;
## With a possible WHERE condition case 1
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND table1.b=2) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=2)) _h
ON _g.b=_h.a ORDER BY _g.a;
## With a possible WHERE condition case 2
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND (table1.b=2 OR table1.b=1)) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=3)) _h
ON _g.b=_h.a ORDER BY _g.a;
## With an impossible WHERE condition case 1
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a AND table1.b=1) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a) _h
ON _g.b=_h.a ORDER BY _g.a;
## With an impossible WHERE condition case 2
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND table1.a=1) _h
ON _g.b=_h.a ORDER BY _g.a;
## With an impossible WHERE condition case 3
SELECT * FROM
(SELECT table1.a, table1.b FROM t1 table1 INNER JOIN t2 table2
ON table1.b=table2.a) _g
LEFT JOIN
(SELECT table1.a FROM t2 table1 INNER JOIN t2 table2
ON table1.a=table2.a AND (table1.a=1 OR table1.a=2)) _h
ON _g.b=_h.a ORDER BY _g.a;
# cleanup
DROP DATABASE mcol_4493;