Skip to content

Commit

Permalink
[CALCITE-2071] Query with IN and OR in WHERE clause returns wrong res…
Browse files Browse the repository at this point in the history
…ult (Vineet Garg)

Initial test case. (Volodymyr Vysotskyi)

Add quidem tests; add a method to derive collations for EnumerableCalc,
without which one of the added tests gets a failed assert when project
is pushed through an EnumerableMergeJoin. (Julian Hyde)

Close #575
  • Loading branch information
vineetgarg02 authored and vvysotskyi committed Dec 18, 2017
1 parent d3c7429 commit 7ebf238
Show file tree
Hide file tree
Showing 5 changed files with 109 additions and 1 deletion.
2 changes: 1 addition & 1 deletion core/src/main/java/org/apache/calcite/plan/RelOptUtil.java
Original file line number Diff line number Diff line change
Expand Up @@ -546,7 +546,7 @@ public static Exists createExistsPlan(
switch (logic) {
case TRUE_FALSE_UNKNOWN:
case UNKNOWN_AS_TRUE:
if (!containsNullableFields(seekRel)) {
if (notIn && !containsNullableFields(seekRel)) {
logic = Logic.TRUE_FALSE;
}
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,7 @@
import org.apache.calcite.rel.RelCollations;
import org.apache.calcite.rel.RelFieldCollation;
import org.apache.calcite.rel.RelNode;
import org.apache.calcite.rel.core.Calc;
import org.apache.calcite.rel.core.Filter;
import org.apache.calcite.rel.core.Join;
import org.apache.calcite.rel.core.Project;
Expand Down Expand Up @@ -149,6 +150,11 @@ public ImmutableList<RelCollation> collations(Project project,
project(mq, project.getInput(), project.getProjects()));
}

public ImmutableList<RelCollation> collations(Calc calc,
RelMetadataQuery mq) {
return ImmutableList.copyOf(calc(mq, calc.getInput(), calc.getProgram()));
}

public ImmutableList<RelCollation> collations(Values values,
RelMetadataQuery mq) {
return ImmutableList.copyOf(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1731,6 +1731,18 @@ private void findSubQueries(
break;
}
if (node instanceof SqlCall) {
switch (kind) {
// Do no change logic for AND, IN and NOT IN expressions;
// but do change logic for OR, NOT and others;
// EXISTS was handled already.
case AND:
case IN:
case NOT_IN:
break;
default:
logic = RelOptUtil.Logic.TRUE_FALSE_UNKNOWN;
break;
}
for (SqlNode operand : ((SqlCall) node).getOperandList()) {
if (operand != null) {
// In the case of an IN expression, locate scalar
Expand Down
18 changes: 18 additions & 0 deletions core/src/test/java/org/apache/calcite/test/JdbcTest.java
Original file line number Diff line number Diff line change
Expand Up @@ -725,6 +725,24 @@ private void checkTableFunctionInModel(Class clazz) {
assertTrue(connection.isClosed());
}

/** Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-2071">[CALCITE-2071]
* Query with IN and OR in WHERE clause returns wrong result</a>.
* More cases in sub-query.iq. */
@Test public void testWhereInOr() {
final String sql = "select \"empid\"\n"
+ "from \"hr\".\"emps\" t\n"
+ "where (\"empid\" in (select \"empid\" from \"hr\".\"emps\")\n"
+ " or \"empid\" in (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11,\n"
+ " 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25))\n"
+ "and \"empid\" in (100, 200, 150)";
CalciteAssert.hr()
.query(sql)
.returnsUnordered("empid=100",
"empid=200",
"empid=150");
}

/** Tests that a driver can be extended with its own parser and can execute
* its own flavor of DDL. */
@Test public void testMockDdl() throws Exception {
Expand Down
72 changes: 72 additions & 0 deletions core/src/test/resources/sql/sub-query.iq
Original file line number Diff line number Diff line change
Expand Up @@ -685,4 +685,76 @@ OR EXISTS (select * from "scott".emp e where emp.deptno = e.deptno + 20);

!ok

# [CALCITE-2071] Query with IN and OR in WHERE clause returns wrong result
select empno
from "scott".emp
where (empno in (select empno from "scott".emp)
or empno in (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14,
15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25))
and empno in (7876, 7698, 7900);
+-------+
| EMPNO |
+-------+
| 7698 |
| 7876 |
| 7900 |
+-------+
(3 rows)

!ok

# Equivalent to above (by de Morgan's law)
select empno
from "scott".emp
where not (empno not in (select empno from "scott".emp)
and empno not in (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14,
15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25))
and empno in (7876, 7698, 7900);
+-------+
| EMPNO |
+-------+
| 7698 |
| 7876 |
| 7900 |
+-------+
(3 rows)

!ok

# Not equivalent to above, but happens to have same result
select empno
from "scott".emp
where (empno = 12345
or empno in (select empno from "scott".emp)
or not empno in (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14,
15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25))
and empno in (7876, 7698, 7900);
+-------+
| EMPNO |
+-------+
| 7698 |
| 7876 |
| 7900 |
+-------+
(3 rows)

!ok

# Similar to above, but never suffered from [CALCITE-2071] because AND
select empno
from "scott".emp
where (empno in (select empno from "scott".emp)
and empno in (7876, 7698, 7900))
and empno in (7876, 7698, 7900);
+-------+
| EMPNO |
+-------+
| 7698 |
| 7876 |
| 7900 |
+-------+
(3 rows)

!ok

# End sub-query.iq

0 comments on commit 7ebf238

Please sign in to comment.