Skip to content

Commit

Permalink
[CALCITE-6028] SqlToRelConverter#substituteSubQuery gives NullPointer…
Browse files Browse the repository at this point in the history
…Exception when convert expr JOIN ... ON ... AND ... IN and if size of IN exceeds IN_SUBQUERY_THRESHOLD
  • Loading branch information
chucheng92 committed Oct 27, 2023
1 parent 79f2f61 commit 1c14cf4
Show file tree
Hide file tree
Showing 5 changed files with 115 additions and 3 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -1235,9 +1235,19 @@ private void substituteSubQuery(Blackboard bb, SubQuery subQuery) {
// SET empno = 1 WHERE emp.empno IN (
// SELECT emp.empno FROM emp WHERE emp.empno = 2)
//
// In such case, when converting SqlUpdate#condition, bb.root is null
// and it makes no sense to do the sub-query substitution.
if (bb.root == null) {
// In such case, when converting SqlUpdate#condition, the bb.root is null,
// but we should skip the expr like 'ON (...) AND (...) IN (...) within JOIN'
// because in this case, bb.root can also be null.
// for example:
// "SELECT e1.empno FROM emps as e1
// LEFT JOIN depts as d1
// ON e1.deptno=d1.deptno
// AND e1.deptno IN (1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21)"
// note: if we use 'WHERE e1.deptno IN (...)',
// the bb.root is not null, doesn't apply to the case here
//
// and SqlUpdate#condition makes no sense to do the sub-query substitution here, return it.
if (bb.root == null && !(bb.scope.getNode() instanceof SqlJoin)) {
return;
}
final RelDataType targetRowType =
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -4934,6 +4934,30 @@ void checkUserDefinedOrderByOver(NullCollation nullCollation) {
.convertsTo("${planNotExpanded}");
}

/**
* Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-6028">[CALCITE-6028]
* SqlToRelConverter#substituteSubQuery gives NullPointerException when convert
* expr JOIN ... ON ... AND ... IN and if size of IN exceeds IN_SUBQUERY_THRESHOLD</a>.
*/
@Test void testInSubQueryWithinJoin0() {
String sql = "SELECT t1.x FROM (values (1, 'a')) as t1(x, y)\n"
+ "left join (values (1, 'b')) as t2(x, y)\n"
+ "ON t1.x=t2.x AND t1.x IN (1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21)";
sql(sql).ok();
}

/**
* As {@link #testInSubQueryWithinJoin0()} but value size of IN < 20.
*/
@Test void testInSubQueryWithinJoin1() {
String sql = "SELECT t1.x FROM (values (1, 'a')) as t1(x, y)\n"
+ "left join (values (1, 'b')) as t2(x, y)\n"
+ "ON t1.x=t2.x AND t1.x IN (1,2,3,4,5)";
sql(sql).ok();
}


/**
* Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-4295">[CALCITE-4295]
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2779,6 +2779,40 @@ FROM dept, emp WHERE emp.deptno = dept.deptno AND emp.sal < (
)]]>
</Resource>
</TestCase>
<TestCase name="testInSubQueryWithinJoin0">
<Resource name="sql">
<![CDATA[SELECT t1.x FROM (values (1, 'a')) as t1(x, y)
left join (values (1, 'b')) as t2(x, y)
ON t1.x=t2.x AND t1.x IN (1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21)]]>
</Resource>
<Resource name="plan">
<![CDATA[
LogicalProject(X=[$0])
LogicalJoin(condition=[=($0, $2)], joinType=[left])
LogicalValues(tuples=[[{ 1, 'a' }]])
LogicalJoin(condition=[=($0, $2)], joinType=[inner])
LogicalValues(tuples=[[{ 1, 'b' }]])
LogicalAggregate(group=[{}], agg#0=[SINGLE_VALUE($0)])
LogicalAggregate(group=[{0}])
LogicalValues(tuples=[[{ 1 }, { 2 }, { 3 }, { 4 }, { 5 }, { 6 }, { 7 }, { 8 }, { 9 }, { 10 }, { 11 }, { 12 }, { 13 }, { 14 }, { 15 }, { 16 }, { 17 }, { 18 }, { 19 }, { 20 }, { 21 }]])
]]>
</Resource>
</TestCase>
<TestCase name="testInSubQueryWithinJoin1">
<Resource name="sql">
<![CDATA[SELECT t1.x FROM (values (1, 'a')) as t1(x, y)
left join (values (1, 'b')) as t2(x, y)
ON t1.x=t2.x AND t1.x IN (1,2,3,4,5)]]>
</Resource>
<Resource name="plan">
<![CDATA[
LogicalProject(X=[$0])
LogicalJoin(condition=[AND(=($0, $2), SEARCH($0, Sarg[1, 2, 3, 4, 5]))], joinType=[left])
LogicalValues(tuples=[[{ 1, 'a' }]])
LogicalValues(tuples=[[{ 1, 'b' }]])
]]>
</Resource>
</TestCase>
<TestCase name="testInToSemiJoin">
<Resource name="sql">
<![CDATA[SELECT empno
Expand Down
37 changes: 37 additions & 0 deletions core/src/test/resources/sql/sub-query.iq
Original file line number Diff line number Diff line change
Expand Up @@ -3685,4 +3685,41 @@ FROM dept d1;

!ok

# Test case for [CALCITE-6028] SqlToRelConverter#substituteSubQuery gives NullPointerException when convert
# expr JOIN ... ON ... AND ... IN and if size of IN exceeds IN_SUBQUERY_THRESHOLD
# IN value size < 20
SELECT e1.empno FROM emp as e1 LEFT JOIN dept as d1 ON e1.deptno=d1.deptno
WHERE e1.deptno IN (1,2,3,4,5,6,7,8,9,10);
+-------+
| EMPNO |
+-------+
| 7782 |
| 7839 |
| 7934 |
+-------+
(3 rows)

!ok

# Test case for [CALCITE-6028] SqlToRelConverter#substituteSubQuery gives NullPointerException when convert
# expr JOIN ... ON ... AND ... IN and if size of IN exceeds IN_SUBQUERY_THRESHOLD
# IN value size > 20
SELECT e1.empno FROM emp as e1 LEFT JOIN dept as d1 ON e1.deptno=d1.deptno
WHERE e1.deptno IN (1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21);
+-------+
| EMPNO |
+-------+
| 7369 |
| 7566 |
| 7782 |
| 7788 |
| 7839 |
| 7876 |
| 7902 |
| 7934 |
+-------+
(8 rows)

!ok

# End sub-query.iq
Original file line number Diff line number Diff line change
Expand Up @@ -10630,6 +10630,13 @@ private static void checkArrayConcatAggFuncFails(SqlOperatorFixture t) {
f.checkNull("floor(cast(null as date) to month)");
}

@Test void testAAA() {
final SqlOperatorFixture f = Fixtures.forOperators(true);
f.check("select t1.x from (values (1, 'a')) as t1(x, y) left join (values (1, 'b')) "
+ "as t2(x, y) on t1.x=t2.x and t1.y "
+ "in (1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21)", "INTEGER NOT NULL", "1");
}

@Test void testCeilFuncDateTime() {
final SqlOperatorFixture f = fixture();
f.enableTypeCoercion(false)
Expand Down

0 comments on commit 1c14cf4

Please sign in to comment.