From 951b324854813adebdc3762106f555401a306a44 Mon Sep 17 00:00:00 2001 From: Ulrich Kramer Date: Mon, 29 Jan 2024 07:43:56 +0100 Subject: [PATCH] [CALCITE-6221] JDBC adapter generates invalid query when the same table is joined multiple times --- .../rel/rel2sql/RelToSqlConverter.java | 49 ++- .../rel/rel2sql/RelToSqlConverterTest.java | 334 ++++++++++-------- .../apache/calcite/test/JdbcAdapterTest.java | 26 ++ 3 files changed, 262 insertions(+), 147 deletions(-) diff --git a/core/src/main/java/org/apache/calcite/rel/rel2sql/RelToSqlConverter.java b/core/src/main/java/org/apache/calcite/rel/rel2sql/RelToSqlConverter.java index 92f8ec7cb33..b9fa21aa9cc 100644 --- a/core/src/main/java/org/apache/calcite/rel/rel2sql/RelToSqlConverter.java +++ b/core/src/main/java/org/apache/calcite/rel/rel2sql/RelToSqlConverter.java @@ -225,7 +225,7 @@ public Result visit(Join e) { break; } final Result leftResult = visitInput(e, 0).resetAlias(); - final Result rightResult = visitInput(e, 1).resetAlias(); + Result rightResult = maybeFixRenamedFields(visitInput(e, 1).resetAlias(), e); final Context leftContext = leftResult.qualifiedContext(); final Context rightContext = rightResult.qualifiedContext(); final SqlNode sqlCondition; @@ -257,6 +257,53 @@ public Result visit(Join e) { return result(join, leftResult, rightResult); } + private Result maybeFixRenamedFields(Result rightResult, Join e) { + Frame last = stack.peekLast(); + if (last != null && last.r instanceof TableModify) { + return rightResult; + } + if (stack.stream().noneMatch(it -> it.r instanceof Filter)) { + return rightResult; + } + List rightFieldNames = e.getRight().getRowType().getFieldNames(); + List fieldNames = e.getRowType().getFieldNames(); + int offset = e.getLeft().getRowType().getFieldCount(); + boolean hasFieldNameCollision = false; + for (int i = 0; i < rightFieldNames.size(); i++) { + if (!rightFieldNames.get(i).equals(fieldNames.get(offset + i))) { + hasFieldNameCollision = true; + } + } + if (!hasFieldNameCollision) { + return rightResult; + } + Builder builder = rightResult.builder(e); + List oldSelectList = new ArrayList<>(); + if (builder.select.getSelectList() == SqlNodeList.SINGLETON_STAR) { + for (int i = 0; i < rightFieldNames.size(); i++) { + oldSelectList.add(new SqlIdentifier(rightFieldNames.get(i), POS)); + } + } else { + for (SqlNode node : builder.select.getSelectList().getList()) { + oldSelectList.add(requireNonNull(node, "node")); + } + } + List selectList = new ArrayList<>(); + // The entries in fieldNames are unique, since they have been generated + // using SqlValidatorUtil.deriveJoinRowType + for (int i = 0; i < rightFieldNames.size(); i++) { + SqlNode column = oldSelectList.get(i); + if (!rightFieldNames.get(i).equals(fieldNames.get(offset + i))) { + column = + SqlStdOperatorTable.AS.createCall(POS, SqlUtil.stripAs(column), + new SqlIdentifier(fieldNames.get(offset + i), POS)); + } + selectList.add(column); + } + builder.setSelect(new SqlNodeList(selectList, POS)); + return builder.result(); + } + protected Result visitAntiOrSemiJoin(Join e) { final Result leftResult = visitInput(e, 0).resetAlias(); final Result rightResult = visitInput(e, 1).resetAlias(); diff --git a/core/src/test/java/org/apache/calcite/rel/rel2sql/RelToSqlConverterTest.java b/core/src/test/java/org/apache/calcite/rel/rel2sql/RelToSqlConverterTest.java index e8632f7a80d..a4c7db417d2 100644 --- a/core/src/test/java/org/apache/calcite/rel/rel2sql/RelToSqlConverterTest.java +++ b/core/src/test/java/org/apache/calcite/rel/rel2sql/RelToSqlConverterTest.java @@ -1807,11 +1807,12 @@ private static String toSql(RelNode root, SqlDialect dialect, + " group by \"product\".\"product_id\"\n" + " having count(*) > 1"; - String expected = "SELECT \"product\".\"product_id\", " - + "MIN(\"sales_fact_1997\".\"store_id\")\n" + String expected = "SELECT \"product\".\"product_id\", MIN(\"t\".\"store_id\")\n" + "FROM \"foodmart\".\"product\"\n" - + "INNER JOIN \"foodmart\".\"sales_fact_1997\" " - + "ON \"product\".\"product_id\" = \"sales_fact_1997\".\"product_id\"\n" + + "INNER JOIN (SELECT \"product_id\" AS \"product_id0\", \"time_id\", \"customer_id\", " + + "\"promotion_id\", \"store_id\", \"store_sales\", \"store_cost\", \"unit_sales\"\n" + + "FROM \"foodmart\".\"sales_fact_1997\") AS \"t\" " + + "ON \"product\".\"product_id\" = \"t\".\"product_id0\"\n" + "GROUP BY \"product\".\"product_id\"\n" + "HAVING COUNT(*) > 1"; sql(query).ok(expected); @@ -1831,12 +1832,15 @@ private static String toSql(RelNode root, SqlDialect dialect, String expected = "SELECT *\n" + "FROM (SELECT \"product\".\"product_id\"," - + " MIN(\"sales_fact_1997\".\"store_id\") AS \"EXPR$1\"\n" + + " MIN(\"t\".\"store_id\") AS \"EXPR$1\"\n" + "FROM \"foodmart\".\"product\"\n" - + "INNER JOIN \"foodmart\".\"sales_fact_1997\" ON \"product\".\"product_id\" = \"sales_fact_1997\".\"product_id\"\n" + + "INNER JOIN (SELECT \"product_id\" AS \"product_id0\", \"time_id\", \"customer_id\", " + + "\"promotion_id\", \"store_id\", \"store_sales\", \"store_cost\", \"unit_sales\"\n" + + "FROM \"foodmart\".\"sales_fact_1997\") AS \"t\" " + + "ON \"product\".\"product_id\" = \"t\".\"product_id0\"\n" + "GROUP BY \"product\".\"product_id\"\n" - + "HAVING COUNT(*) > 1) AS \"t2\"\n" - + "WHERE \"t2\".\"product_id\" > 100"; + + "HAVING COUNT(*) > 1) AS \"t3\"\n" + + "WHERE \"t3\".\"product_id\" > 100"; sql(query).ok(expected); } @@ -3519,16 +3523,27 @@ private SqlDialect nonOrdinalDialect() { + "and pc.\"product_department\" = 'Snacks'\n"; final String expected = "SELECT *\n" + "FROM \"foodmart\".\"sales_fact_1997\"\n" - + "INNER JOIN \"foodmart\".\"customer\" " - + "ON \"sales_fact_1997\".\"customer_id\" = \"customer\"" - + ".\"customer_id\"\n" - + "INNER JOIN \"foodmart\".\"product\" " - + "ON \"sales_fact_1997\".\"product_id\" = \"product\".\"product_id\"\n" - + "INNER JOIN \"foodmart\".\"product_class\" " - + "ON \"product\".\"product_class_id\" = \"product_class\"" - + ".\"product_class_id\"\n" - + "WHERE \"customer\".\"city\" = 'San Francisco' AND " - + "\"product_class\".\"product_department\" = 'Snacks'"; + + "INNER JOIN (SELECT \"customer_id\" AS \"customer_id0\", \"account_num\", \"lname\", " + + "\"fname\", \"mi\", \"address1\", \"address2\", \"address3\", \"address4\", \"city\", " + + "\"state_province\", \"postal_code\", \"country\", \"customer_region_id\", \"phone1\", " + + "\"phone2\", \"birthdate\", \"marital_status\", \"yearly_income\", \"gender\", " + + "\"total_children\", \"num_children_at_home\", \"education\", \"date_accnt_opened\", " + + "\"member_card\", \"occupation\", \"houseowner\", \"num_cars_owned\", \"fullname\"\n" + + "FROM \"foodmart\".\"customer\") AS \"t\" " + + "ON \"sales_fact_1997\".\"customer_id\" = \"t\".\"customer_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\", \"product_id\" AS \"product_id0\", " + + "\"brand_name\", \"product_name\", \"SKU\", \"SRP\", \"gross_weight\", \"net_weight\", " + + "\"recyclable_package\", \"low_fat\", \"units_per_case\", \"cases_per_pallet\", " + + "\"shelf_width\", \"shelf_height\", \"shelf_depth\"\n" + + "FROM \"foodmart\".\"product\") AS \"t0\" " + + "ON \"sales_fact_1997\".\"product_id\" = \"t0\".\"product_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\" AS \"product_class_id0\", " + + "\"product_subcategory\", \"product_category\", \"product_department\", " + + "\"product_family\"\n" + + "FROM \"foodmart\".\"product_class\") AS \"t1\" " + + "ON \"t0\".\"product_class_id\" = \"t1\".\"product_class_id0\"\n" + + "WHERE \"t\".\"city\" = 'San Francisco' AND " + + "\"t1\".\"product_department\" = 'Snacks'"; sql(query).ok(expected); } @@ -3540,72 +3555,82 @@ private SqlDialect nonOrdinalDialect() { + " join \"product_class\" as pc using (\"product_class_id\")\n" + "where c.\"city\" = 'San Francisco'\n" + "and pc.\"product_department\" = 'Snacks'\n"; - final String expected = "SELECT" - + " \"product\".\"product_class_id\"," - + " \"sales_fact_1997\".\"product_id\"," - + " \"sales_fact_1997\".\"customer_id\"," - + " \"sales_fact_1997\".\"time_id\"," - + " \"sales_fact_1997\".\"promotion_id\"," - + " \"sales_fact_1997\".\"store_id\"," - + " \"sales_fact_1997\".\"store_sales\"," - + " \"sales_fact_1997\".\"store_cost\"," - + " \"sales_fact_1997\".\"unit_sales\"," - + " \"customer\".\"account_num\"," - + " \"customer\".\"lname\"," - + " \"customer\".\"fname\"," - + " \"customer\".\"mi\"," - + " \"customer\".\"address1\"," - + " \"customer\".\"address2\"," - + " \"customer\".\"address3\"," - + " \"customer\".\"address4\"," - + " \"customer\".\"city\"," - + " \"customer\".\"state_province\"," - + " \"customer\".\"postal_code\"," - + " \"customer\".\"country\"," - + " \"customer\".\"customer_region_id\"," - + " \"customer\".\"phone1\"," - + " \"customer\".\"phone2\"," - + " \"customer\".\"birthdate\"," - + " \"customer\".\"marital_status\"," - + " \"customer\".\"yearly_income\"," - + " \"customer\".\"gender\"," - + " \"customer\".\"total_children\"," - + " \"customer\".\"num_children_at_home\"," - + " \"customer\".\"education\"," - + " \"customer\".\"date_accnt_opened\"," - + " \"customer\".\"member_card\"," - + " \"customer\".\"occupation\"," - + " \"customer\".\"houseowner\"," - + " \"customer\".\"num_cars_owned\"," - + " \"customer\".\"fullname\"," - + " \"product\".\"brand_name\"," - + " \"product\".\"product_name\"," - + " \"product\".\"SKU\"," - + " \"product\".\"SRP\"," - + " \"product\".\"gross_weight\"," - + " \"product\".\"net_weight\"," - + " \"product\".\"recyclable_package\"," - + " \"product\".\"low_fat\"," - + " \"product\".\"units_per_case\"," - + " \"product\".\"cases_per_pallet\"," - + " \"product\".\"shelf_width\"," - + " \"product\".\"shelf_height\"," - + " \"product\".\"shelf_depth\"," - + " \"product_class\".\"product_subcategory\"," - + " \"product_class\".\"product_category\"," - + " \"product_class\".\"product_department\"," - + " \"product_class\".\"product_family\"\n" + final String expected = "SELECT " + + "\"t0\".\"product_class_id\", " + + "\"sales_fact_1997\".\"product_id\", " + + "\"sales_fact_1997\".\"customer_id\", " + + "\"sales_fact_1997\".\"time_id\", " + + "\"sales_fact_1997\".\"promotion_id\", " + + "\"sales_fact_1997\".\"store_id\", " + + "\"sales_fact_1997\".\"store_sales\", " + + "\"sales_fact_1997\".\"store_cost\", " + + "\"sales_fact_1997\".\"unit_sales\", " + + "\"t\".\"account_num\", " + + "\"t\".\"lname\", " + + "\"t\".\"fname\", " + + "\"t\".\"mi\", " + + "\"t\".\"address1\", " + + "\"t\".\"address2\", " + + "\"t\".\"address3\", " + + "\"t\".\"address4\", " + + "\"t\".\"city\", " + + "\"t\".\"state_province\", " + + "\"t\".\"postal_code\", " + + "\"t\".\"country\", " + + "\"t\".\"customer_region_id\", " + + "\"t\".\"phone1\", " + + "\"t\".\"phone2\", " + + "\"t\".\"birthdate\", " + + "\"t\".\"marital_status\", " + + "\"t\".\"yearly_income\", " + + "\"t\".\"gender\", " + + "\"t\".\"total_children\", " + + "\"t\".\"num_children_at_home\", " + + "\"t\".\"education\", " + + "\"t\".\"date_accnt_opened\", " + + "\"t\".\"member_card\", " + + "\"t\".\"occupation\", " + + "\"t\".\"houseowner\", " + + "\"t\".\"num_cars_owned\", " + + "\"t\".\"fullname\", " + + "\"t0\".\"brand_name\", " + + "\"t0\".\"product_name\", " + + "\"t0\".\"SKU\", " + + "\"t0\".\"SRP\", " + + "\"t0\".\"gross_weight\", " + + "\"t0\".\"net_weight\", " + + "\"t0\".\"recyclable_package\", " + + "\"t0\".\"low_fat\", " + + "\"t0\".\"units_per_case\", " + + "\"t0\".\"cases_per_pallet\", " + + "\"t0\".\"shelf_width\", " + + "\"t0\".\"shelf_height\", " + + "\"t0\".\"shelf_depth\", " + + "\"t1\".\"product_subcategory\", " + + "\"t1\".\"product_category\", " + + "\"t1\".\"product_department\", " + + "\"t1\".\"product_family\"\n" + "FROM \"foodmart\".\"sales_fact_1997\"\n" - + "INNER JOIN \"foodmart\".\"customer\" " - + "ON \"sales_fact_1997\".\"customer_id\" = \"customer\"" - + ".\"customer_id\"\n" - + "INNER JOIN \"foodmart\".\"product\" " - + "ON \"sales_fact_1997\".\"product_id\" = \"product\".\"product_id\"\n" - + "INNER JOIN \"foodmart\".\"product_class\" " - + "ON \"product\".\"product_class_id\" = \"product_class\"" - + ".\"product_class_id\"\n" - + "WHERE \"customer\".\"city\" = 'San Francisco' AND " - + "\"product_class\".\"product_department\" = 'Snacks'"; + + "INNER JOIN (SELECT \"customer_id\" AS \"customer_id0\", \"account_num\", \"lname\", " + + "\"fname\", \"mi\", \"address1\", \"address2\", \"address3\", \"address4\", \"city\", " + + "\"state_province\", \"postal_code\", \"country\", \"customer_region_id\", \"phone1\", " + + "\"phone2\", \"birthdate\", \"marital_status\", \"yearly_income\", \"gender\", " + + "\"total_children\", \"num_children_at_home\", \"education\", \"date_accnt_opened\", " + + "\"member_card\", \"occupation\", \"houseowner\", \"num_cars_owned\", \"fullname\"\n" + + "FROM \"foodmart\".\"customer\") AS \"t\" " + + "ON \"sales_fact_1997\".\"customer_id\" = \"t\".\"customer_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\", \"product_id\" AS \"product_id0\", " + + "\"brand_name\", \"product_name\", \"SKU\", \"SRP\", \"gross_weight\", \"net_weight\", " + + "\"recyclable_package\", \"low_fat\", \"units_per_case\", \"cases_per_pallet\", " + + "\"shelf_width\", \"shelf_height\", \"shelf_depth\"\n" + + "FROM \"foodmart\".\"product\") AS \"t0\" " + + "ON \"sales_fact_1997\".\"product_id\" = \"t0\".\"product_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\" AS \"product_class_id0\", " + + "\"product_subcategory\", \"product_category\", \"product_department\", " + + "\"product_family\"\n" + + "FROM \"foodmart\".\"product_class\") AS \"t1\" " + + "ON \"t0\".\"product_class_id\" = \"t1\".\"product_class_id0\"\n" + + "WHERE \"t\".\"city\" = 'San Francisco' AND \"t1\".\"product_department\" = 'Snacks'"; sql(query).ok(expected); } @@ -3783,12 +3808,11 @@ private SqlDialect nonOrdinalDialect() { + "from \"foodmart\".\"employee\" A join \"foodmart\".\"department\" B\n" + "on A.\"department_id\" = B.\"department_id\" " + "where A.\"employee_id\" < 1000"; - final String expected = "SELECT" - + " employee.employee_id, department.department_id\n" + final String expected = "SELECT employee.employee_id, t.department_id\n" + "FROM foodmart.employee AS employee\n" - + "INNER JOIN foodmart.department AS department " - + "ON employee.department_id = department.department_id\n" - + "WHERE employee.employee_id < 1000"; + + "INNER JOIN (SELECT department_id AS department_id0, department_description\n" + + "FROM foodmart.department AS department) AS t " + + "ON employee.department_id = department.department_id\nWHERE employee.employee_id < 1000"; sql(query).withDb2().ok(expected); } @@ -3797,12 +3821,19 @@ private SqlDialect nonOrdinalDialect() { + "\"foodmart\".\"employee\" A join \"foodmart\".\"employee\" B\n" + "on A.\"department_id\" = B.\"department_id\" " + "where B.\"employee_id\" < 2000"; - final String expected = "SELECT " - + "employee.employee_id, employee0.employee_id AS employee_id0\n" + final String expected = "SELECT employee.employee_id, t.employee_id AS employee_id0\n" + "FROM foodmart.employee AS employee\n" - + "INNER JOIN foodmart.employee AS employee0 " + + "INNER JOIN (SELECT employee_id AS employee_id0, full_name AS full_name0, " + + "first_name AS first_name0, last_name AS last_name0, position_id AS position_id0, " + + "position_title AS position_title0, store_id AS store_id0, " + + "department_id AS department_id0, birth_date AS birth_date0, " + + "hire_date AS hire_date0, end_date AS end_date0, salary AS salary0, " + + "supervisor_id AS supervisor_id0, education_level AS education_level0, " + + "marital_status AS marital_status0, gender AS gender0, " + + "management_role AS management_role0\n" + + "FROM foodmart.employee AS employee0) AS t " + "ON employee.department_id = employee0.department_id\n" - + "WHERE employee0.employee_id < 2000"; + + "WHERE t.employee_id < 2000"; sql(query).withDb2().ok(expected); } @@ -3914,18 +3945,19 @@ private SqlDialect nonOrdinalDialect() { final String sql = "SELECT v1.deptno, v2.deptno\n" + "FROM dept v1 LEFT JOIN emp v2 ON v1.deptno = v2.deptno\n" + "WHERE v2.job LIKE 'PRESIDENT'"; - final String expected = "SELECT \"DEPT\".\"DEPTNO\"," - + " \"EMP\".\"DEPTNO\" AS \"DEPTNO0\"\n" + final String expected = "SELECT \"DEPT\".\"DEPTNO\", \"t\".\"DEPTNO0\"\n" + "FROM \"SCOTT\".\"DEPT\"\n" - + "LEFT JOIN \"SCOTT\".\"EMP\"" - + " ON \"DEPT\".\"DEPTNO\" = \"EMP\".\"DEPTNO\"\n" - + "WHERE \"EMP\".\"JOB\" LIKE 'PRESIDENT'"; + + "LEFT JOIN (SELECT \"EMPNO\", \"ENAME\", \"JOB\", \"MGR\", " + + "\"HIREDATE\", \"SAL\", \"COMM\", \"DEPTNO\" AS \"DEPTNO0\"\n" + + "FROM \"SCOTT\".\"EMP\") AS \"t\" ON \"DEPT\".\"DEPTNO\" = \"t\".\"DEPTNO0\"\n" + + "WHERE \"t\".\"JOB\" LIKE 'PRESIDENT'"; // DB2 does not have implicit aliases, so generates explicit "AS DEPT" // and "AS EMP" - final String expectedDb2 = "SELECT DEPT.DEPTNO, EMP.DEPTNO AS DEPTNO0\n" + final String expectedDb2 = "SELECT DEPT.DEPTNO, t.DEPTNO AS DEPTNO0\n" + "FROM SCOTT.DEPT AS DEPT\n" - + "LEFT JOIN SCOTT.EMP AS EMP ON DEPT.DEPTNO = EMP.DEPTNO\n" - + "WHERE EMP.JOB LIKE 'PRESIDENT'"; + + "LEFT JOIN (SELECT EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO AS DEPTNO0\n" + + "FROM SCOTT.EMP AS EMP) AS t " + + "ON DEPT.DEPTNO = EMP.DEPTNO\nWHERE t.JOB LIKE 'PRESIDENT'"; sql(sql) .schema(CalciteAssert.SchemaSpec.JDBC_SCOTT) .ok(expected) @@ -3977,14 +4009,13 @@ private SqlDialect nonOrdinalDialect() { + " AND d.deptno < 15\n" + " AND d.deptno > 10\n" + "WHERE e.job LIKE 'PRESIDENT'"; - final String expected = "SELECT \"DEPT\".\"DEPTNO\"," - + " \"EMP\".\"DEPTNO\" AS \"DEPTNO0\"\n" + final String expected = "SELECT \"DEPT\".\"DEPTNO\", \"t\".\"DEPTNO0\"\n" + "FROM \"SCOTT\".\"DEPT\"\n" - + "LEFT JOIN \"SCOTT\".\"EMP\" " - + "ON \"DEPT\".\"DEPTNO\" = \"EMP\".\"DEPTNO\" " - + "AND (\"DEPT\".\"DEPTNO\" > 10" - + " AND \"DEPT\".\"DEPTNO\" < 15)\n" - + "WHERE \"EMP\".\"JOB\" LIKE 'PRESIDENT'"; + + "LEFT JOIN (SELECT \"EMPNO\", \"ENAME\", \"JOB\", \"MGR\", \"HIREDATE\", \"SAL\", " + + "\"COMM\", \"DEPTNO\" AS \"DEPTNO0\"\nFROM \"SCOTT\".\"EMP\") AS \"t\" " + + "ON \"DEPT\".\"DEPTNO\" = \"t\".\"DEPTNO0\" " + + "AND (\"DEPT\".\"DEPTNO\" > 10 AND \"DEPT\".\"DEPTNO\" < 15)\n" + + "WHERE \"t\".\"JOB\" LIKE 'PRESIDENT'"; sql(sql) .schema(CalciteAssert.SchemaSpec.JDBC_SCOTT) .ok(expected); @@ -3998,13 +4029,13 @@ private SqlDialect nonOrdinalDialect() { + "FROM dept AS d LEFT JOIN emp AS e\n" + " ON CASE WHEN e.job = 'PRESIDENT' THEN true ELSE d.deptno = 10 END\n" + "WHERE e.job LIKE 'PRESIDENT'"; - final String expected = "SELECT \"DEPT\".\"DEPTNO\"," - + " \"EMP\".\"DEPTNO\" AS \"DEPTNO0\"\n" + final String expected = "SELECT \"DEPT\".\"DEPTNO\", \"t\".\"DEPTNO0\"\n" + "FROM \"SCOTT\".\"DEPT\"\n" - + "LEFT JOIN \"SCOTT\".\"EMP\"" - + " ON CASE WHEN \"EMP\".\"JOB\" = 'PRESIDENT' THEN TRUE" - + " ELSE CAST(\"DEPT\".\"DEPTNO\" AS INTEGER) = 10 END\n" - + "WHERE \"EMP\".\"JOB\" LIKE 'PRESIDENT'"; + + "LEFT JOIN (SELECT \"EMPNO\", \"ENAME\", \"JOB\", \"MGR\", \"HIREDATE\", \"SAL\", " + + "\"COMM\", \"DEPTNO\" AS \"DEPTNO0\"\nFROM \"SCOTT\".\"EMP\") AS \"t\" ON " + + "CASE WHEN \"t\".\"JOB\" = 'PRESIDENT' THEN TRUE " + + "ELSE CAST(\"DEPT\".\"DEPTNO\" AS INTEGER) = 10 END\n" + + "WHERE \"t\".\"JOB\" LIKE 'PRESIDENT'"; sql(sql) .schema(CalciteAssert.SchemaSpec.JDBC_SCOTT) .ok(expected); @@ -4015,13 +4046,13 @@ private SqlDialect nonOrdinalDialect() { + "FROM dept AS d LEFT JOIN emp AS e ON d.deptno = e.deptno\n" + "WHERE CASE WHEN e.job = 'PRESIDENT' THEN true\n" + " ELSE d.deptno = 10 END\n"; - final String expected = "SELECT \"DEPT\".\"DEPTNO\"," - + " \"EMP\".\"DEPTNO\" AS \"DEPTNO0\"\n" + final String expected = "SELECT \"DEPT\".\"DEPTNO\", \"t\".\"DEPTNO0\"\n" + "FROM \"SCOTT\".\"DEPT\"\n" - + "LEFT JOIN \"SCOTT\".\"EMP\"" - + " ON \"DEPT\".\"DEPTNO\" = \"EMP\".\"DEPTNO\"\n" - + "WHERE CASE WHEN \"EMP\".\"JOB\" = 'PRESIDENT' THEN TRUE" - + " ELSE CAST(\"DEPT\".\"DEPTNO\" AS INTEGER) = 10 END"; + + "LEFT JOIN (SELECT \"EMPNO\", \"ENAME\", \"JOB\", \"MGR\", \"HIREDATE\", \"SAL\", " + + "\"COMM\", \"DEPTNO\" AS \"DEPTNO0\"\nFROM \"SCOTT\".\"EMP\") AS \"t\" " + + "ON \"DEPT\".\"DEPTNO\" = \"t\".\"DEPTNO0\"\n" + + "WHERE CASE WHEN \"t\".\"JOB\" = 'PRESIDENT' THEN TRUE " + + "ELSE CAST(\"DEPT\".\"DEPTNO\" AS INTEGER) = 10 END"; sql(sql) .schema(CalciteAssert.SchemaSpec.JDBC_SCOTT) .ok(expected); @@ -5330,23 +5361,31 @@ private void checkLiteral2(String expression, String expected) { final String expected = "SELECT *\n" + "FROM (SELECT *\n" + "FROM \"foodmart\".\"sales_fact_1997\"\n" - + "INNER JOIN \"foodmart\".\"customer\" " - + "ON \"sales_fact_1997\".\"customer_id\" = \"customer\".\"customer_id\"\n" - + "INNER JOIN \"foodmart\".\"product\" " - + "ON \"sales_fact_1997\".\"product_id\" = \"product\".\"product_id\"\n" - + "INNER JOIN \"foodmart\".\"product_class\" " - + "ON \"product\".\"product_class_id\" = \"product_class\".\"product_class_id\"\n" - + "WHERE \"customer\".\"city\" = 'San Francisco' " - + "AND \"product_class\".\"product_department\" = 'Snacks') " - + "MATCH_RECOGNIZE(\n" - + "ONE ROW PER MATCH\n" - + "AFTER MATCH SKIP TO NEXT ROW\n" + + "INNER JOIN (SELECT \"customer_id\" AS \"customer_id0\", \"account_num\", " + + "\"lname\", \"fname\", \"mi\", \"address1\", \"address2\", \"address3\", " + + "\"address4\", \"city\", \"state_province\", \"postal_code\", \"country\", " + + "\"customer_region_id\", \"phone1\", \"phone2\", \"birthdate\", \"marital_status\", " + + "\"yearly_income\", \"gender\", \"total_children\", \"num_children_at_home\", " + + "\"education\", \"date_accnt_opened\", \"member_card\", \"occupation\", " + + "\"houseowner\", \"num_cars_owned\", \"fullname\"\n" + + "FROM \"foodmart\".\"customer\") AS \"t\" " + + "ON \"sales_fact_1997\".\"customer_id\" = \"t\".\"customer_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\", \"product_id\" AS \"product_id0\", " + + "\"brand_name\", \"product_name\", \"SKU\", \"SRP\", \"gross_weight\", \"net_weight\", " + + "\"recyclable_package\", \"low_fat\", \"units_per_case\", \"cases_per_pallet\", " + + "\"shelf_width\", \"shelf_height\", \"shelf_depth\"\n" + + "FROM \"foodmart\".\"product\") AS \"t0\" " + + "ON \"sales_fact_1997\".\"product_id\" = \"t0\".\"product_id0\"\n" + + "INNER JOIN (SELECT \"product_class_id\" AS \"product_class_id0\", " + + "\"product_subcategory\", \"product_category\", \"product_department\", " + + "\"product_family\"\n" + + "FROM \"foodmart\".\"product_class\") AS \"t1\" " + + "ON \"t0\".\"product_class_id\" = \"t1\".\"product_class_id0\"\n" + + "WHERE \"t\".\"city\" = 'San Francisco' AND \"t1\".\"product_department\" = 'Snacks') " + + "MATCH_RECOGNIZE(\nONE ROW PER MATCH\nAFTER MATCH SKIP TO NEXT ROW\n" + "PATTERN (\"STRT\" \"DOWN\" + \"UP\" +)\n" - + "DEFINE " - + "\"DOWN\" AS PREV(\"DOWN\".\"net_weight\", 0) < " - + "PREV(\"DOWN\".\"net_weight\", 1), " - + "\"UP\" AS PREV(\"UP\".\"net_weight\", 0) > " - + "PREV(\"UP\".\"net_weight\", 1))\n" + + "DEFINE \"DOWN\" AS PREV(\"DOWN\".\"net_weight\", 0) < PREV(\"DOWN\".\"net_weight\", 1), " + + "\"UP\" AS PREV(\"UP\".\"net_weight\", 0) > PREV(\"UP\".\"net_weight\", 1))\n" + "ORDER BY \"net_weight\""; sql(sql).ok(expected); } @@ -6917,15 +6956,17 @@ private void checkLiteral2(String expression, String expected) { + " where A.\"department_id\" = ( select min( A.\"department_id\") from \"foodmart\".\"department\" B where 1=2 )"; final String expectedOracle = "SELECT \"employee\".\"department_id\"\n" + "FROM \"foodmart\".\"employee\"\n" - + "INNER JOIN (SELECT \"t1\".\"department_id\" \"department_id0\", MIN(\"t1\".\"department_id\") \"EXPR$0\"\n" + + "INNER JOIN (SELECT \"t2\".\"department_id0\", " + + "MIN(\"t2\".\"department_id0\") \"EXPR$0\"\n" + "FROM (SELECT NULL \"department_id\", NULL \"department_description\"\n" + "FROM \"DUAL\"\n" + "WHERE 1 = 0) \"t\",\n" - + "(SELECT \"department_id\"\n" + + "(SELECT \"department_id\" \"department_id0\"\n" + "FROM \"foodmart\".\"employee\"\n" - + "GROUP BY \"department_id\") \"t1\"\n" - + "GROUP BY \"t1\".\"department_id\"\n" - + "HAVING \"t1\".\"department_id\" = MIN(\"t1\".\"department_id\")) \"t4\" ON \"employee\".\"department_id\" = \"t4\".\"department_id0\""; + + "GROUP BY \"department_id\") \"t2\"\n" + + "GROUP BY \"t2\".\"department_id0\"\n" + + "HAVING \"t2\".\"department_id0\" = MIN(\"t2\".\"department_id0\")) \"t5\" " + + "ON \"employee\".\"department_id\" = \"t5\".\"department_id0\""; final String expectedNoExpand = "SELECT \"department_id\"\n" + "FROM \"foodmart\".\"employee\"\n" + "WHERE \"department_id\" = (((SELECT MIN(\"employee\".\"department_id\")\n" @@ -6933,15 +6974,16 @@ private void checkLiteral2(String expression, String expected) { + "WHERE 1 = 2)))"; final String expected = "SELECT \"employee\".\"department_id\"\n" + "FROM \"foodmart\".\"employee\"\n" - + "INNER JOIN (SELECT \"t1\".\"department_id\" AS \"department_id0\", MIN(\"t1\".\"department_id\") AS \"EXPR$0\"\n" + + "INNER JOIN (SELECT \"t2\".\"department_id0\", " + + "MIN(\"t2\".\"department_id0\") AS \"EXPR$0\"\n" + "FROM (SELECT *\n" + "FROM (VALUES (NULL, NULL)) AS \"t\" (\"department_id\", \"department_description\")\n" + "WHERE 1 = 0) AS \"t\",\n" - + "(SELECT \"department_id\"\n" - + "FROM \"foodmart\".\"employee\"\n" - + "GROUP BY \"department_id\") AS \"t1\"\n" - + "GROUP BY \"t1\".\"department_id\"\n" - + "HAVING \"t1\".\"department_id\" = MIN(\"t1\".\"department_id\")) AS \"t4\" ON \"employee\".\"department_id\" = \"t4\".\"department_id0\""; + + "(SELECT \"department_id\" AS \"department_id0\"\nFROM \"foodmart\".\"employee\"\n" + + "GROUP BY \"department_id\") AS \"t2\"\n" + + "GROUP BY \"t2\".\"department_id0\"\n" + + "HAVING \"t2\".\"department_id0\" = MIN(\"t2\".\"department_id0\")) AS \"t5\" " + + "ON \"employee\".\"department_id\" = \"t5\".\"department_id0\""; sql(query) .ok(expectedNoExpand) .withConfig(c -> c.withExpand(true)).ok(expected) diff --git a/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java b/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java index ea57e5d9455..c6e9551a517 100644 --- a/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java +++ b/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java @@ -1147,6 +1147,32 @@ private LockWrapper exclusiveCleanDb(Connection c) throws SQLException { }); } + /** + * Test case for + * [CALCITE-6221].*/ + @Test void testUnknownColumn() { + CalciteAssert.model(JdbcTest.SCOTT_MODEL) + .query("SELECT\n" + + " \"content-format-owner\",\n" + + " \"content-owner\"\n" + + "FROM\n" + + " (\n" + + " SELECT\n" + + " d1.dname AS \"content-format-owner\",\n" + + " d2.dname || ' ' AS \"content-owner\"\n" + + " FROM\n" + + " scott.emp e1\n" + + " left outer join scott.dept d1 on e1.deptno = d1.deptno\n" + + " left outer join scott.dept d2 on e1.deptno = d2.deptno\n" + + " left outer join scott.emp e2 on e1.deptno = e2.deptno\n" + + " GROUP BY\n" + + " d1.dname,\n" + + " d2.dname\n" + + " )\n" + + "WHERE\n" + + " \"content-owner\" IN (?)") + .runs(); + } /** Acquires a lock, and releases it when closed. */ static class LockWrapper implements AutoCloseable { private final Lock lock;