From ae5feaf39879e02ef020b35d9d2d0dccd1f3ae56 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 | 56 +- .../rel/rel2sql/RelToSqlConverterTest.java | 587 +++++++++++------- .../apache/calcite/test/JdbcAdapterTest.java | 79 ++- .../org/apache/calcite/test/PigRelOpTest.java | 67 +- 4 files changed, 479 insertions(+), 310 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 92f8ec7cb336..d566e53ede8d 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 @@ -102,17 +102,7 @@ import org.checkerframework.checker.nullness.qual.Nullable; -import java.util.ArrayDeque; -import java.util.ArrayList; -import java.util.Arrays; -import java.util.Collection; -import java.util.Collections; -import java.util.Deque; -import java.util.List; -import java.util.Map; -import java.util.Set; -import java.util.SortedSet; -import java.util.TreeSet; +import java.util.*; import java.util.stream.Collectors; import java.util.stream.Stream; @@ -225,7 +215,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 +247,48 @@ 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; + } + 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(Objects.requireNonNull(node)); + } + } + List selectList = new ArrayList<>(); + 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 e8632f7a80d5..ae37f30aad00 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 @@ -809,8 +809,8 @@ private static String toSql(RelNode root, SqlDialect dialect, // RelFieldTrimmer maybe build the RelNode. relFn(fn).ok("SELECT \"t\".\"V\" AS \"l_v\"\n" + "FROM (VALUES (1, 2)) AS \"t\" (\"K\", \"V\")\n" - + "INNER JOIN " - + "(VALUES (1)) AS \"t0\" (\"K\") ON \"t\".\"K\" = \"t0\".\"K\""); + + "INNER JOIN (SELECT \"K\" AS \"K0\"\n" + + "FROM (VALUES (1)) AS \"t\" (\"K\")) AS \"t1\" ON \"t\".\"K\" = \"t1\".\"K0\""); } /** As {@link #testTrimmedAggregateUnderProject()} @@ -1544,11 +1544,14 @@ private static String toSql(RelNode root, SqlDialect dialect, builder.field(2, 0, "DEPTNO"))) .project(builder.field("DEPTNO")) .build(); - final String expectedSql = "SELECT \"DEPTNO\"\n" - + "FROM \"scott\".\"DEPT\"\n" + final String expectedSql = "SELECT \"DEPTNO\"\nFROM \"scott\".\"DEPT\"\n" + "WHERE EXISTS (SELECT 1\n" + "FROM \"scott\".\"EMP\"\n" - + "INNER JOIN \"scott\".\"EMP\" AS \"EMP0\" ON \"EMP\".\"EMPNO\" = \"EMP0\".\"EMPNO\"\n" + + "INNER JOIN (SELECT \"EMPNO\" AS \"EMPNO0\", \"ENAME\" AS \"ENAME0\", " + + "\"JOB\" AS \"JOB0\", \"MGR\" AS \"MGR0\", \"HIREDATE\" AS \"HIREDATE0\", " + + "\"SAL\" AS \"SAL0\", \"COMM\" AS \"COMM0\", \"DEPTNO\" AS \"DEPTNO0\"\n" + + "FROM \"scott\".\"EMP\") AS \"t\" " + + "ON \"EMP\".\"EMPNO\" = \"t\".\"EMPNO0\"\n" + "WHERE \"DEPT\".\"DEPTNO\" = \"EMP\".\"DEPTNO\")"; assertThat(toSql(root), isLinux(expectedSql)); } @@ -1577,12 +1580,13 @@ private static String toSql(RelNode root, SqlDialect dialect, .build(); final String expectedSql = "SELECT \"DEPT\".\"DEPTNO\"\n" + "FROM \"scott\".\"DEPT\"\n" - + "INNER JOIN (SELECT *\n" + + "INNER JOIN (SELECT \"EMPNO\", \"ENAME\", \"JOB\", \"MGR\", \"HIREDATE\", \"SAL\", " + + "\"COMM\", \"DEPTNO\" AS \"DEPTNO0\"\n" + "FROM \"scott\".\"EMP\"\n" + "WHERE EXISTS (SELECT 1\n" + "FROM \"scott\".\"EMP\" AS \"EMP0\"\n" - + "WHERE \"EMP\".\"EMPNO\" = \"EMP0\".\"EMPNO\")) AS \"t\" ON \"DEPT\".\"DEPTNO\" = \"t\"" - + ".\"DEPTNO\""; + + "WHERE \"EMP\".\"EMPNO\" = \"EMP0\".\"EMPNO\")) AS \"t0\" " + + "ON \"DEPT\".\"DEPTNO\" = \"t0\".\"DEPTNO0\""; assertThat(toSql(root), isLinux(expectedSql)); } @@ -1769,9 +1773,10 @@ private static String toSql(RelNode root, SqlDialect dialect, .build(); final String expectedSql = "SELECT *\n" + "FROM \"scott\".\"EMP\"\n" - + "LEFT JOIN \"scott\".\"DEPT\" " - + "ON \"EMP\".\"DEPTNO\" = \"DEPT\".\"DEPTNO\" " - + "AND \"DEPT\".\"DNAME\" LIKE 'ACCOUNTING'"; + + "LEFT JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\", \"LOC\"\n" + + "FROM \"scott\".\"DEPT\") AS \"t\" " + + "ON \"EMP\".\"DEPTNO\" = \"t\".\"DEPTNO0\" " + + "AND \"t\".\"DNAME\" LIKE 'ACCOUNTING'"; relFn(relFn).ok(expectedSql); } @@ -1807,11 +1812,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 +1837,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 +3528,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 +3560,81 @@ 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); } @@ -3620,8 +3649,9 @@ private SqlDialect nonOrdinalDialect() { final String expected = "SELECT *\n" + "FROM (SELECT sales_fact_1997.customer_id\n" + "FROM foodmart.sales_fact_1997 AS sales_fact_1997) AS t\n" - + "INNER JOIN (SELECT sales_fact_19970.customer_id\n" - + "FROM foodmart.sales_fact_1997 AS sales_fact_19970) AS t0 ON t.customer_id = t0.customer_id"; + + "INNER JOIN (SELECT sales_fact_19970.customer_id AS customer_id0\n" + + "FROM foodmart.sales_fact_1997 AS sales_fact_19970) AS t1 " + + "ON t.customer_id = t0.customer_id"; sql(query).withDb2().ok(expected); } @@ -3630,7 +3660,12 @@ private SqlDialect nonOrdinalDialect() { String query = "select * from \"department\" , \"employee\""; String expected = "SELECT *\n" + "FROM \"foodmart\".\"department\",\n" - + "\"foodmart\".\"employee\""; + + "(SELECT \"employee_id\", \"full_name\", \"first_name\", \"last_name\", " + + "\"position_id\", \"position_title\", \"store_id\", " + + "\"department_id\" AS \"department_id0\", \"birth_date\", \"hire_date\", \"end_date\", " + + "\"salary\", \"supervisor_id\", \"education_level\", \"marital_status\", \"gender\", " + + "\"management_role\"\n" + + "FROM \"foodmart\".\"employee\") AS \"t\""; sql(query).ok(expected); } @@ -3664,9 +3699,9 @@ private SqlDialect nonOrdinalDialect() { .build(); final String expectedSql = "SELECT *\n" + "FROM \"scott\".\"EMP\"\n" - + "LEFT JOIN \"scott\".\"DEPT\" " - + "ON \"EMP\".\"DEPTNO\" = \"DEPT\".\"DEPTNO\" " - + "AND \"DEPT\".\"DNAME\" NOT LIKE 'ACCOUNTING'"; + + "LEFT JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\", \"LOC\"\n" + + "FROM \"scott\".\"DEPT\") AS \"t\" " + + "ON \"EMP\".\"DEPTNO\" = \"t\".\"DEPTNO0\" AND \"t\".\"DNAME\" NOT LIKE 'ACCOUNTING'"; relFn(relFn).ok(expectedSql); } @@ -3675,7 +3710,11 @@ private SqlDialect nonOrdinalDialect() { + "INNER JOIN \"employee\" ON TRUE"; String expected = "SELECT *\n" + "FROM \"foodmart\".\"department\",\n" - + "\"foodmart\".\"employee\""; + + "(SELECT \"employee_id\", \"full_name\", \"first_name\", \"last_name\", \"position_id\", " + + "\"position_title\", \"store_id\", \"department_id\" AS \"department_id0\", " + + "\"birth_date\", \"hire_date\", \"end_date\", \"salary\", \"supervisor_id\", " + + "\"education_level\", \"marital_status\", \"gender\", \"management_role\"\n" + + "FROM \"foodmart\".\"employee\") AS \"t\""; sql(query).ok(expected); } @@ -3684,7 +3723,12 @@ private SqlDialect nonOrdinalDialect() { + "FULL JOIN \"employee\" ON TRUE"; String expected = "SELECT *\n" + "FROM \"foodmart\".\"department\"\n" - + "FULL JOIN \"foodmart\".\"employee\" ON TRUE"; + + "FULL JOIN (SELECT \"employee_id\", \"full_name\", \"first_name\", \"last_name\", " + + "\"position_id\", \"position_title\", \"store_id\", " + + "\"department_id\" AS \"department_id0\", \"birth_date\", \"hire_date\", \"end_date\", " + + "\"salary\", \"supervisor_id\", \"education_level\", \"marital_status\", \"gender\", " + + "\"management_role\"\n" + + "FROM \"foodmart\".\"employee\") AS \"t\" ON TRUE"; sql(query).ok(expected); } @@ -3706,16 +3750,14 @@ private SqlDialect nonOrdinalDialect() { String query = "select * from \"department\" where \"department_id\" in (\n" + " select \"department_id\" from \"employee\"\n" + " where \"store_id\" < 150)"; - final String expected = "SELECT " - + "\"department\".\"department_id\", \"department\"" - + ".\"department_description\"\n" + final String expected = "SELECT \"department\".\"department_id\", " + + "\"department\".\"department_description\"\n" + "FROM \"foodmart\".\"department\"\n" - + "INNER JOIN " - + "(SELECT \"department_id\"\n" + + "INNER JOIN (SELECT \"department_id\" AS \"department_id0\"\n" + "FROM \"foodmart\".\"employee\"\n" + "WHERE \"store_id\" < 150\n" - + "GROUP BY \"department_id\") AS \"t1\" " - + "ON \"department\".\"department_id\" = \"t1\".\"department_id\""; + + "GROUP BY \"department_id\") AS \"t2\" " + + "ON \"department\".\"department_id\" = \"t2\".\"department_id0\""; sql(query).withConfig(c -> c.withExpand(true)).ok(expected); } @@ -3729,7 +3771,8 @@ private SqlDialect nonOrdinalDialect() { + "on A.\"department_id\" = B.\"department_id\""; final String expected = "SELECT *\n" + "FROM foodmart.employee AS employee\n" - + "INNER JOIN foodmart.department AS department " + + "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"; sql(query).withDb2().ok(expected); } @@ -3740,8 +3783,15 @@ private SqlDialect nonOrdinalDialect() { + "on A.\"department_id\" = B.\"department_id\""; final String expected = "SELECT *\n" + "FROM foodmart.employee AS employee\n" - + "INNER JOIN foodmart.employee AS employee0 " - + "ON employee.department_id = employee0.department_id"; + + "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"; sql(query).withDb2().ok(expected); } @@ -3749,10 +3799,10 @@ private SqlDialect nonOrdinalDialect() { String query = "select A.\"employee_id\", B.\"department_id\" " + "from \"foodmart\".\"employee\" A join \"foodmart\".\"department\" B\n" + "on A.\"department_id\" = B.\"department_id\""; - 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 " + + "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"; sql(query).withDb2().ok(expected); } @@ -3761,11 +3811,17 @@ private SqlDialect nonOrdinalDialect() { String query = "select A.\"employee_id\", B.\"employee_id\" from " + "\"foodmart\".\"employee\" A join \"foodmart\".\"employee\" B\n" + "on A.\"department_id\" = B.\"department_id\""; - 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 " - + "ON employee.department_id = employee0.department_id"; + + "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"; sql(query).withDb2().ok(expected); } @@ -3783,12 +3839,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 +3852,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 +3976,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) @@ -3950,15 +4013,23 @@ private SqlDialect nonOrdinalDialect() { + "\"t3\".\"product_id\" is not null)"; String expected = "SELECT *\n" + "FROM \"foodmart\".\"sales_fact_1997\"\n" - + "INNER JOIN \"foodmart\".\"customer\" " - + "ON \"sales_fact_1997\".\"customer_id\" = \"customer\".\"customer_id\"" - + " OR \"sales_fact_1997\".\"customer_id\" IS NULL" - + " AND \"customer\".\"customer_id\" IS NULL" - + " OR \"customer\".\"occupation\" IS NULL\n" - + "INNER JOIN \"foodmart\".\"product\" " - + "ON \"sales_fact_1997\".\"product_id\" = \"product\".\"product_id\"" - + " OR \"sales_fact_1997\".\"product_id\" IS NOT NULL" - + " OR \"product\".\"product_id\" IS NOT NULL"; + + "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\" " + + "OR \"sales_fact_1997\".\"customer_id\" IS NULL " + + "AND \"t\".\"customer_id0\" IS NULL OR \"t\".\"occupation\" IS NULL\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\" " + + "OR \"sales_fact_1997\".\"product_id\" IS NOT NULL OR \"t0\".\"product_id0\" IS NOT NULL"; // The hook prevents RelBuilder from removing "FALSE AND FALSE" and such try (Hook.Closeable ignore = Hook.REL_BUILDER_SIMPLIFY.addThread(Hook.propertyJ(false))) { @@ -3977,14 +4048,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 +4068,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 +4085,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); @@ -4390,15 +4460,16 @@ private void checkLiteral2(String expression, String expected) { "select sum(e1.\"store_sales\"), sum(e2.\"store_sales\") from \"sales_fact_dec_1998\" as " + "e1 , \"sales_fact_dec_1998\" as e2 where e1.\"product_id\" = e2.\"product_id\""; - String expect = "SELECT SUM(CAST(\"t\".\"EXPR$0\" * \"t0\".\"$f1\" AS DECIMAL" - + "(19, 4))), SUM(CAST(\"t\".\"$f2\" * \"t0\".\"EXPR$1\" AS DECIMAL(19, 4)))\n" + String expect = "SELECT SUM(CAST(\"t\".\"EXPR$0\" * \"t1\".\"$f1\" AS DECIMAL(19, 4))), " + + "SUM(CAST(\"t\".\"$f2\" * \"t1\".\"EXPR$1\" AS DECIMAL(19, 4)))\n" + "FROM (SELECT \"product_id\", SUM(\"store_sales\") AS \"EXPR$0\", COUNT(*) AS \"$f2\"\n" + "FROM \"foodmart\".\"sales_fact_dec_1998\"\n" + "GROUP BY \"product_id\") AS \"t\"\n" - + "INNER JOIN " - + "(SELECT \"product_id\", COUNT(*) AS \"$f1\", SUM(\"store_sales\") AS \"EXPR$1\"\n" + + "INNER JOIN (SELECT \"product_id\" AS \"product_id0\", COUNT(*) AS \"$f1\", " + + "SUM(\"store_sales\") AS \"EXPR$1\"\n" + "FROM \"foodmart\".\"sales_fact_dec_1998\"\n" - + "GROUP BY \"product_id\") AS \"t0\" ON \"t\".\"product_id\" = \"t0\".\"product_id\""; + + "GROUP BY \"product_id\") AS \"t1\" " + + "ON \"t\".\"product_id\" = \"t1\".\"product_id0\""; HepProgramBuilder builder = new HepProgramBuilder(); builder.addRuleClass(FilterJoinRule.class); @@ -4422,8 +4493,9 @@ private void checkLiteral2(String expression, String expected) { final String expected = "SELECT \"t\".\"customer_id\", SUM(\"t\".\"$f1\")\n" + "FROM (SELECT \"customer_id\", \"store_sales\" * \"store_cost\" AS \"$f1\"\n" + "FROM \"foodmart\".\"sales_fact_1997\") AS \"t\"\n" - + "INNER JOIN (SELECT \"customer_id\"\n" - + "FROM \"foodmart\".\"customer\") AS \"t0\" ON \"t\".\"customer_id\" = \"t0\".\"customer_id\"\n" + + "INNER JOIN (SELECT \"customer_id\" AS \"customer_id0\"\n" + + "FROM \"foodmart\".\"customer\") AS \"t1\" " + + "ON \"t\".\"customer_id\" = \"t1\".\"customer_id0\"\n" + "GROUP BY \"t\".\"customer_id\""; RuleSet rules = RuleSets.ofList(CoreRules.PROJECT_JOIN_TRANSPOSE); sql(sql).optimize(rules, null).ok(expected); @@ -4437,9 +4509,9 @@ private void checkLiteral2(String expression, String expected) { final String expected = "SELECT \"t\".\"customer_id\", \"t\".\"total\"\n" + "FROM (SELECT \"customer_id\", \"store_sales\" * \"store_cost\" AS \"total\"\n" + "FROM \"foodmart\".\"sales_fact_1997\") AS \"t\"\n" - + "INNER JOIN (SELECT \"customer_id\"\n" - + "FROM \"foodmart\".\"customer\") AS \"t0\" ON \"t\".\"customer_id\" = \"t0\"" - + ".\"customer_id\""; + + "INNER JOIN (SELECT \"customer_id\" AS \"customer_id0\"\n" + + "FROM \"foodmart\".\"customer\") AS \"t1\" " + + "ON \"t\".\"customer_id\" = \"t1\".\"customer_id0\""; RuleSet rules = RuleSets.ofList(CoreRules.PROJECT_JOIN_TRANSPOSE); sql(sql).optimize(rules, null).ok(expected); } @@ -5043,10 +5115,11 @@ private void checkLiteral2(String expression, String expected) { @Test void testNumericScale() { final String sql = "WITH v(x) AS (VALUES('4.2')) " + " SELECT x1 + x2 FROM v AS v1(x1), v AS V2(x2)"; - final String expected = "SELECT CAST(\"t\".\"EXPR$0\" AS " - + "DECIMAL(39, 10)) + CAST(\"t0\".\"EXPR$0\" AS " - + "DECIMAL(39, 10))\nFROM (VALUES ('4.2')) AS " - + "\"t\" (\"EXPR$0\"),\n(VALUES ('4.2')) AS \"t0\" (\"EXPR$0\")"; + final String expected = "SELECT CAST(\"t\".\"EXPR$0\" AS DECIMAL(39, 10)) + " + + "CAST(\"t1\".\"EXPR$00\" AS DECIMAL(39, 10))\n" + + "FROM (VALUES ('4.2')) AS \"t\" (\"EXPR$0\"),\n" + + "(SELECT \"EXPR$0\" AS \"EXPR$00\"\n" + + "FROM (VALUES ('4.2')) AS \"t\" (\"EXPR$0\")) AS \"t1\""; sql(sql).withPostgresqlModifiedDecimalTypeSystem() .ok(expected); } @@ -5330,23 +5403,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); } @@ -6212,18 +6293,17 @@ private void checkLiteral2(String expression, String expected) { .project(builder.field("a")) .build(); final String expectedSql = "SELECT \"t\".\"a\"\n" - + "FROM (VALUES (1, 'x '),\n" - + "(2, 'yy')) AS \"t\" (\"a\", \"b\")\n" - + "FULL JOIN (VALUES (1, 'x '),\n" - + "(2, 'yy')) AS \"t0\" (\"a\", \"b\") ON TRUE"; + + "FROM (VALUES (1, 'x '),\n(2, 'yy')) AS \"t\" (\"a\", \"b\")\n" + + "FULL JOIN (SELECT \"a\" AS \"a0\", \"b\" AS \"b0\"\n" + + "FROM (VALUES (1, 'x '),\n(2, 'yy')) AS \"t\" (\"a\", \"b\")) AS \"t1\" ON TRUE"; assertThat(toSql(root), isLinux(expectedSql)); // Now with indentation. final String expectedSql2 = "SELECT \"t\".\"a\"\n" - + "FROM (VALUES (1, 'x '),\n" - + " (2, 'yy')) AS \"t\" (\"a\", \"b\")\n" - + " FULL JOIN (VALUES (1, 'x '),\n" - + " (2, 'yy')) AS \"t0\" (\"a\", \"b\") ON TRUE"; + + "FROM (VALUES (1, 'x '),\n (2, 'yy')) AS \"t\" (\"a\", \"b\")\n" + + " FULL JOIN (SELECT \"a\" AS \"a0\", \"b\" AS \"b0\"\n" + + " FROM (VALUES (1, 'x '),\n" + + " (2, 'yy')) AS \"t\" (\"a\", \"b\")) AS \"t1\" ON TRUE"; assertThat( toSql(root, DatabaseProduct.CALCITE.getDialect(), c -> c.withIndentation(2)), @@ -6292,17 +6372,21 @@ private void checkLiteral2(String expression, String expected) { + " group by c.\"city\", s.\"store_sales\") AS mytable\n" + "group by mytable.\"city\""; - final String expected = "SELECT \"t0\".\"city\"," - + " SUM(\"t0\".\"store_sales\") AS \"my-alias\"\n" - + "FROM (SELECT \"customer\".\"city\"," - + " \"sales_fact_1997\".\"store_sales\"\n" + final String expected = "SELECT \"t1\".\"city\", " + + "SUM(\"t1\".\"store_sales\") AS \"my-alias\"\n" + + "FROM (SELECT \"t\".\"city\", \"sales_fact_1997\".\"store_sales\"\n" + "FROM \"foodmart\".\"sales_fact_1997\"\n" - + "INNER JOIN \"foodmart\".\"customer\"" - + " ON \"sales_fact_1997\".\"customer_id\"" - + " = \"customer\".\"customer_id\"\n" - + "GROUP BY \"customer\".\"city\"," - + " \"sales_fact_1997\".\"store_sales\") AS \"t0\"\n" - + "GROUP BY \"t0\".\"city\""; + + "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" + + "GROUP BY \"t\".\"city\", \"sales_fact_1997\".\"store_sales\") AS \"t1\"\n" + + "GROUP BY \"t1\".\"city\""; sql(query).ok(expected); } @@ -6583,10 +6667,12 @@ private void checkLiteral2(String expression, String expected) { @Test void testCrossJoinEmulation() { final String expectedSpark = "SELECT *\n" + "FROM foodmart.employee\n" - + "CROSS JOIN foodmart.department"; + + "CROSS JOIN (SELECT department_id department_id0, department_description\n" + + "FROM foodmart.department) t"; final String expectedMysql = "SELECT *\n" + "FROM `foodmart`.`employee`,\n" - + "`foodmart`.`department`"; + + "(SELECT `department_id` AS `department_id0`, `department_description`\n" + + "FROM `foodmart`.`department`) AS `t`"; Consumer fn = sql -> sql(sql) .withSpark().ok(expectedSpark) @@ -6606,13 +6692,21 @@ private void checkLiteral2(String expression, String expected) { + "inner join \"employee\" as e on true\n" + "cross join \"department\" as d"; final String expectedMysql = "SELECT *\n" - + "FROM `foodmart`.`store`,\n" - + "`foodmart`.`employee`,\n" - + "`foodmart`.`department`"; + + "FROM `foodmart`.`store`,\n(SELECT `employee_id`, `full_name`, `first_name`, " + + "`last_name`, `position_id`, `position_title`, `store_id` AS `store_id0`, " + + "`department_id`, `birth_date`, `hire_date`, `end_date`, `salary`, " + + "`supervisor_id`, `education_level`, `marital_status`, `gender`, `management_role`\n" + + "FROM `foodmart`.`employee`) AS `t`,\n" + + "(SELECT `department_id` AS `department_id0`, `department_description`\n" + + "FROM `foodmart`.`department`) AS `t0`"; final String expectedSpark = "SELECT *\n" + "FROM foodmart.store\n" - + "CROSS JOIN foodmart.employee\n" - + "CROSS JOIN foodmart.department"; + + "CROSS JOIN (SELECT employee_id, full_name, first_name, last_name, position_id, " + + "position_title, store_id store_id0, department_id, birth_date, hire_date, end_date, " + + "salary, supervisor_id, education_level, marital_status, gender, management_role\n" + + "FROM foodmart.employee) t\n" + + "CROSS JOIN (SELECT department_id department_id0, department_description\n" + + "FROM foodmart.department) t0"; sql(sql) .withMysql().ok(expectedMysql) .withSpark().ok(expectedSpark); @@ -6627,8 +6721,13 @@ private void checkLiteral2(String expression, String expected) { + "cross join \"department\" as d"; final String expectedMysql = "SELECT *\n" + "FROM `foodmart`.`store`\n" - + "LEFT JOIN `foodmart`.`employee` ON TRUE\n" - + "CROSS JOIN `foodmart`.`department`"; + + "LEFT JOIN (SELECT `employee_id`, `full_name`, `first_name`, `last_name`, " + + "`position_id`, `position_title`, `store_id` AS `store_id0`, `department_id`, " + + "`birth_date`, `hire_date`, `end_date`, `salary`, `supervisor_id`, `education_level`, " + + "`marital_status`, `gender`, `management_role`\nFROM `foodmart`.`employee`) AS `t` " + + "ON TRUE\n" + + "CROSS JOIN (SELECT `department_id` AS `department_id0`, `department_description`\n" + + "FROM `foodmart`.`department`) AS `t0`"; sql(sql).withMysql().ok(expectedMysql); } @@ -6639,10 +6738,13 @@ private void checkLiteral2(String expression, String expected) { + "from \"store\" as s\n" + "cross join \"employee\" as e\n" + "right join \"department\" as d on true"; - final String expectedMysql = "SELECT *\n" - + "FROM `foodmart`.`store`\n" - + "CROSS JOIN `foodmart`.`employee`\n" - + "RIGHT JOIN `foodmart`.`department` ON TRUE"; + final String expectedMysql = "SELECT *\nFROM `foodmart`.`store`\n" + + "CROSS JOIN (SELECT `employee_id`, `full_name`, `first_name`, `last_name`, " + + "`position_id`, `position_title`, `store_id` AS `store_id0`, `department_id`, " + + "`birth_date`, `hire_date`, `end_date`, `salary`, `supervisor_id`, `education_level`, " + + "`marital_status`, `gender`, `management_role`\nFROM `foodmart`.`employee`) AS `t`\n" + + "RIGHT JOIN (SELECT `department_id` AS `department_id0`, `department_description`\n" + + "FROM `foodmart`.`department`) AS `t0` ON TRUE"; sql(sql).withMysql().ok(expectedMysql); } @@ -6655,9 +6757,13 @@ private void checkLiteral2(String expression, String expected) { + "cross join \"department\" as d"; final String expectedMysql = "SELECT *\n" + "FROM `foodmart`.`store`\n" - + "INNER JOIN `foodmart`.`employee`" - + " ON `store`.`store_id` = `employee`.`store_id`\n" - + "CROSS JOIN `foodmart`.`department`"; + + "INNER JOIN (SELECT `employee_id`, `full_name`, `first_name`, `last_name`, " + + "`position_id`, `position_title`, `store_id` AS `store_id0`, `department_id`, " + + "`birth_date`, `hire_date`, `end_date`, `salary`, `supervisor_id`, `education_level`, " + + "`marital_status`, `gender`, `management_role`\nFROM `foodmart`.`employee`) AS `t` " + + "ON `store`.`store_id` = `t`.`store_id0`\n" + + "CROSS JOIN (SELECT `department_id` AS `department_id0`, `department_description`\n" + + "FROM `foodmart`.`department`) AS `t0`"; sql(sql).withMysql().ok(expectedMysql); } @@ -6917,15 +7023,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 +7041,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 ea57e5d94550..bb265dced747 100644 --- a/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java +++ b/core/src/test/java/org/apache/calcite/test/JdbcAdapterTest.java @@ -170,12 +170,12 @@ class JdbcAdapterTest { .runs() .enable(CalciteAssert.DB == CalciteAssert.DatabaseInstance.HSQLDB) .planHasSql("SELECT \"t\".\"EMPNO\", \"t\".\"ENAME\", " - + "\"t\".\"DEPTNO\", \"t0\".\"DNAME\"\n" + + "\"t\".\"DEPTNO\", \"t1\".\"DNAME\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"DEPTNO\"\n" + "FROM \"SCOTT\".\"EMP\") AS \"t\"\n" - + "INNER JOIN (SELECT \"DEPTNO\", \"DNAME\"\n" - + "FROM \"SCOTT\".\"DEPT\") AS \"t0\" " - + "ON \"t\".\"DEPTNO\" = \"t0\".\"DEPTNO\""); + + "INNER JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\"\n" + + "FROM \"SCOTT\".\"DEPT\") AS \"t1\" " + + "ON \"t\".\"DEPTNO\" = \"t1\".\"DEPTNO0\""); } @Test void testPushDownSort() { @@ -283,9 +283,9 @@ class JdbcAdapterTest { + "\"t\".\"EMPNO\" AS \"EMPNO0\", \"t\".\"ENAME\" AS \"ENAME0\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"MGR\", \"SAL\"\n" + "FROM \"SCOTT\".\"EMP\") AS \"t\"\n" - + "INNER JOIN (SELECT \"EMPNO\", \"SAL\"\n" - + "FROM \"SCOTT\".\"EMP\") AS \"t0\" " - + "ON \"t\".\"MGR\" = \"t0\".\"EMPNO\" AND \"t\".\"SAL\" > \"t0\".\"SAL\""); + + "INNER JOIN (SELECT \"EMPNO\" AS \"EMPNO0\", \"SAL\" AS \"SAL0\"\n" + + "FROM \"SCOTT\".\"EMP\") AS \"t1\" " + + "ON \"t\".\"MGR\" = \"t1\".\"EMPNO0\" AND \"t\".\"SAL\" > \"t1\".\"SAL0\""); } @Test void testMixedJoinWithOrPlan() { @@ -306,10 +306,11 @@ class JdbcAdapterTest { + "\"t\".\"EMPNO\" AS \"EMPNO0\", \"t\".\"ENAME\" AS \"ENAME0\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"MGR\", \"HIREDATE\", \"SAL\"\n" + "FROM \"SCOTT\".\"EMP\") AS \"t\"\n" - + "INNER JOIN (SELECT \"EMPNO\", \"HIREDATE\", \"SAL\"\n" - + "FROM \"SCOTT\".\"EMP\") AS \"t0\" " - + "ON \"t\".\"MGR\" = \"t0\".\"EMPNO\" " - + "AND (\"t\".\"SAL\" > \"t0\".\"SAL\" OR \"t\".\"HIREDATE\" < \"t0\".\"HIREDATE\")"); + + "INNER JOIN (SELECT \"EMPNO\" AS \"EMPNO0\", \"HIREDATE\" AS \"HIREDATE0\", " + + "\"SAL\" AS \"SAL0\"\n" + + "FROM \"SCOTT\".\"EMP\") AS \"t1\" " + + "ON \"t\".\"MGR\" = \"t1\".\"EMPNO0\" " + + "AND (\"t\".\"SAL\" > \"t1\".\"SAL0\" OR \"t\".\"HIREDATE\" < \"t1\".\"HIREDATE0\")"); } @Test void testJoin3TablesPlan() { @@ -331,11 +332,12 @@ class JdbcAdapterTest { .runs() .enable(CalciteAssert.DB == CalciteAssert.DatabaseInstance.HSQLDB) .planHasSql("SELECT \"t\".\"EMPNO\", \"t\".\"ENAME\", " - + "\"t0\".\"DNAME\", \"SALGRADE\".\"GRADE\"\n" + + "\"t1\".\"DNAME\", \"SALGRADE\".\"GRADE\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"SAL\", \"DEPTNO\"\n" + "FROM \"SCOTT\".\"EMP\") AS \"t\"\n" - + "INNER JOIN (SELECT \"DEPTNO\", \"DNAME\"\n" - + "FROM \"SCOTT\".\"DEPT\") AS \"t0\" ON \"t\".\"DEPTNO\" = \"t0\".\"DEPTNO\"\n" + + "INNER JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", " + + "\"DNAME\"\nFROM \"SCOTT\".\"DEPT\") AS \"t1\" " + + "ON \"t\".\"DEPTNO\" = \"t1\".\"DEPTNO0\"\n" + "INNER JOIN \"SCOTT\".\"SALGRADE\" " + "ON \"t\".\"SAL\" > \"SALGRADE\".\"LOSAL\" " + "AND \"t\".\"SAL\" < \"SALGRADE\".\"HISAL\""); @@ -356,10 +358,10 @@ class JdbcAdapterTest { .runs() .enable(CalciteAssert.DB == CalciteAssert.DatabaseInstance.HSQLDB) .planHasSql("SELECT \"t\".\"EMPNO\", \"t\".\"ENAME\", " - + "\"t0\".\"DEPTNO\", \"t0\".\"DNAME\"\n" + + "\"t1\".\"DEPTNO0\" AS \"DEPTNO\", \"t1\".\"DNAME\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"DEPTNO\"\nFROM \"SCOTT\".\"EMP\") AS \"t\"\n" - + "INNER JOIN (SELECT \"DEPTNO\", \"DNAME\"\n" - + "FROM \"SCOTT\".\"DEPT\") AS \"t0\" ON \"t\".\"DEPTNO\" = \"t0\".\"DEPTNO\""); + + "INNER JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\"\n" + + "FROM \"SCOTT\".\"DEPT\") AS \"t1\" ON \"t\".\"DEPTNO\" = \"t1\".\"DEPTNO0\""); } @Test void testCartesianJoinWithoutKeyPlan() { @@ -393,12 +395,12 @@ class JdbcAdapterTest { .runs() .enable(CalciteAssert.DB == CalciteAssert.DatabaseInstance.HSQLDB) .planHasSql("SELECT \"t0\".\"EMPNO\", \"t0\".\"ENAME\", " - + "\"t1\".\"DEPTNO\", \"t1\".\"DNAME\"\n" + + "\"t2\".\"DEPTNO0\" AS \"DEPTNO\", \"t2\".\"DNAME\"\n" + "FROM (SELECT \"EMPNO\", \"ENAME\", \"DEPTNO\"\n" + "FROM \"SCOTT\".\"EMP\"\n" + "WHERE CAST(\"DEPTNO\" AS INTEGER) = 20) AS \"t0\"\n" - + "INNER JOIN (SELECT \"DEPTNO\", \"DNAME\"\n" - + "FROM \"SCOTT\".\"DEPT\") AS \"t1\" ON \"t0\".\"DEPTNO\" = \"t1\".\"DEPTNO\""); + + "INNER JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\"\n" + + "FROM \"SCOTT\".\"DEPT\") AS \"t2\" ON \"t0\".\"DEPTNO\" = \"t2\".\"DEPTNO0\""); } @Test void testJoinConditionAlwaysTruePushDown() { @@ -476,17 +478,16 @@ class JdbcAdapterTest { + " GROUP BY emp.deptno, dept.dname)"; final String expected = "c=1\n"; final String expectedSql = "SELECT COUNT(*) AS \"c\"\n" - + "FROM (SELECT \"t0\".\"DEPTNO\", \"t2\".\"DNAME\"\n" + + "FROM (SELECT \"t0\".\"DEPTNO\", \"t3\".\"DNAME\"\n" + "FROM (SELECT \"HISAL\"\n" + "FROM \"SCOTT\".\"SALGRADE\") AS \"t\"\n" + "INNER JOIN ((SELECT \"COMM\", \"DEPTNO\"\n" + "FROM \"SCOTT\".\"EMP\") AS \"t0\" " - + "INNER JOIN (SELECT \"DEPTNO\", \"DNAME\"\n" - + "FROM \"SCOTT\".\"DEPT\"\n" - + "WHERE \"DNAME\" LIKE '%A%') AS \"t2\" " - + "ON \"t0\".\"DEPTNO\" = \"t2\".\"DEPTNO\") " + + "INNER JOIN (SELECT \"DEPTNO\" AS \"DEPTNO0\", \"DNAME\"\nFROM \"SCOTT\".\"DEPT\"\n" + + "WHERE \"DNAME\" LIKE '%A%') AS \"t3\" " + + "ON \"t0\".\"DEPTNO\" = \"t3\".\"DEPTNO0\") " + "ON \"t\".\"HISAL\" = \"t0\".\"COMM\"\n" - + "GROUP BY \"t0\".\"DEPTNO\", \"t2\".\"DNAME\") AS \"t3\""; + + "GROUP BY \"t0\".\"DEPTNO\", \"t3\".\"DNAME\") AS \"t4\""; CalciteAssert.model(JdbcTest.SCOTT_MODEL) .with(Lex.MYSQL) .query(sql) @@ -1147,6 +1148,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; diff --git a/piglet/src/test/java/org/apache/calcite/test/PigRelOpTest.java b/piglet/src/test/java/org/apache/calcite/test/PigRelOpTest.java index 0da4ea734cdf..689a6e081b24 100644 --- a/piglet/src/test/java/org/apache/calcite/test/PigRelOpTest.java +++ b/piglet/src/test/java/org/apache/calcite/test/PigRelOpTest.java @@ -636,16 +636,17 @@ private Fluent pig(String script) { final String innerSql = "" + "SELECT *\n" + "FROM scott.EMP\n" - + " INNER JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO"; + + " INNER JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0"; pig(innerScript).assertRel(hasTree(plan)) .assertSql(is(innerSql)); final String leftScript = scanScript + "C = JOIN A BY DEPTNO LEFT OUTER, B BY DEPTNO;\n"; final String leftSql = "" - + "SELECT *\n" - + "FROM scott.EMP\n" - + " LEFT JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO"; + + "SELECT *\nFROM scott.EMP\n" + + " LEFT JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0"; final String leftPlan = "" + "LogicalJoin(condition=[=($7, $8)], joinType=[left])\n" + scanPlan; @@ -657,7 +658,8 @@ private Fluent pig(String script) { final String rightSql = "" + "SELECT *\n" + "FROM scott.EMP\n" - + " RIGHT JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO"; + + " RIGHT JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0"; final String rightPlan = "LogicalJoin(condition=[=($7, $8)], joinType=[right])\n" + scanPlan; @@ -673,7 +675,8 @@ private Fluent pig(String script) { final String fullSql = "" + "SELECT *\n" + "FROM scott.EMP\n" - + " FULL JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO"; + + " FULL JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0"; final String fullResult = "" + "(7369,SMITH,CLERK,7902,1980-12-17,800.00,null,20,20," + "RESEARCH,DALLAS)\n" @@ -729,10 +732,11 @@ private Fluent pig(String script) { final String sql = "" + "SELECT *\n" + "FROM scott.EMP\n" - + " INNER JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO\n" - + " INNER JOIN (SELECT *\n" + + " INNER JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0\n" + + " INNER JOIN (SELECT DEPTNO AS DEPTNO1, DNAME AS DNAME0, LOC AS LOC0\n" + " FROM scott.DEPT\n" - + " WHERE LOC = 'CHICAGO') AS t ON EMP.DEPTNO = t.DEPTNO"; + + " WHERE LOC = 'CHICAGO') AS t1 ON EMP.DEPTNO = t1.DEPTNO1"; final String result = "" + "(7499,ALLEN,SALESMAN,7698,1981-02-20,1600.00,300.00,30,30," + "SALES,CHICAGO,30,SALES," @@ -777,12 +781,11 @@ private Fluent pig(String script) { final String sql2 = "" + "SELECT *\n" + "FROM scott.EMP\n" - + " INNER JOIN scott.DEPT ON EMP.DEPTNO = DEPT.DEPTNO " - + "AND EMP.ENAME = DEPT.DNAME\n" - + " INNER JOIN (SELECT *\n" + + " INNER JOIN (SELECT DEPTNO AS DEPTNO0, DNAME, LOC\n" + + " FROM scott.DEPT) AS t ON EMP.DEPTNO = t.DEPTNO0 AND EMP.ENAME = t.DNAME\n" + + " INNER JOIN (SELECT DEPTNO AS DEPTNO1, DNAME AS DNAME0, LOC AS LOC0\n" + " FROM scott.DEPT\n" - + " WHERE LOC = 'CHICAGO') AS t ON EMP.DEPTNO = t.DEPTNO " - + "AND DEPT.DNAME = t.DNAME"; + + " WHERE LOC = 'CHICAGO') AS t1 ON EMP.DEPTNO = t1.DEPTNO1 AND t.DNAME = t1.DNAME0"; pig(script2).assertRel(hasTree(plan2)) .assertSql(is(sql2)); } @@ -805,9 +808,9 @@ private Fluent pig(String script) { + "SELECT *\n" + "FROM (SELECT DEPTNO\n" + " FROM scott.DEPT) AS t,\n" - + " (SELECT DEPTNO\n" + + " (SELECT DEPTNO AS DEPTNO0\n" + " FROM scott.DEPT\n" - + " WHERE DEPTNO <= 20) AS t1"; + + " WHERE DEPTNO <= 20) AS t2"; final String result = "" + "(10,10)\n" + "(10,20)\n" @@ -859,15 +862,15 @@ private Fluent pig(String script) { + "(40,20,30)\n" + "(40,20,40)\n"; final String sql2 = "" - + "SELECT *\n" - + "FROM (SELECT DEPTNO\n" + + "SELECT *\nF" + + "ROM (SELECT DEPTNO\n" + " FROM scott.DEPT) AS t,\n" - + " (SELECT DEPTNO\n" + + " (SELECT DEPTNO AS DEPTNO0\n" + " FROM scott.DEPT\n" - + " WHERE DEPTNO <= 20) AS t1,\n" - + " (SELECT DEPTNO\n" + + " WHERE DEPTNO <= 20) AS t2,\n" + + " (SELECT DEPTNO AS DEPTNO1\n" + " FROM scott.DEPT\n" - + " WHERE DEPTNO > 20) AS t3"; + + " WHERE DEPTNO > 20) AS t5"; pig(script2).assertRel(hasTree(plan2)) .assertResult(is(result2)) .assertSql(is(sql2)); @@ -1591,25 +1594,23 @@ private Fluent pig(String script) { + "(50,{(40,OPERATIONS,BOSTON)},{},{})\n"; final String sql = "" - + "SELECT CASE WHEN t4.DEPTNO IS NOT NULL THEN t4.DEPTNO ELSE t7.DEPTNO END " - + "AS DEPTNO, t4.A, t4.B, t7.C\n" - + "FROM (SELECT CASE WHEN t0.$f0 IS NOT NULL THEN t0.$f0 ELSE t3.DEPTNO END " - + "AS DEPTNO, t0.A, t3.B\n" - + " FROM (SELECT DEPTNO + 10 AS $f0, " - + "COLLECT(ROW(DEPTNO, DNAME, LOC)) AS A\n" + + "SELECT CASE WHEN t4.DEPTNO IS NOT NULL THEN t4.DEPTNO " + + "ELSE t8.DEPTNO0 END AS DEPTNO, t4.A, t4.B, t8.C\n" + + "FROM (SELECT CASE WHEN t0.$f0 IS NOT NULL THEN t0.$f0 " + + "ELSE t3.DEPTNO END AS DEPTNO, t0.A, t3.B\n" + + " FROM (SELECT DEPTNO + 10 AS $f0, COLLECT(ROW(DEPTNO, DNAME, LOC)) AS A\n" + " FROM scott.DEPT\n" + " GROUP BY DEPTNO + 10) AS t0\n" + " FULL JOIN (SELECT CAST(DEPTNO AS INTEGER) AS DEPTNO, " + "COLLECT(ROW(DEPTNO, DNAME, LOC)) AS B\n" + " FROM scott.DEPT\n" + " WHERE DEPTNO <= 30\n" - + " GROUP BY CAST(DEPTNO AS INTEGER)) AS t3 " - + "ON t0.$f0 = t3.DEPTNO) AS t4\n" - + " FULL JOIN (SELECT CAST(DEPTNO AS INTEGER) AS DEPTNO, COLLECT(ROW(DEPTNO, DNAME, " - + "LOC)) AS C\n" + + " GROUP BY CAST(DEPTNO AS INTEGER)) AS t3 ON t0.$f0 = t3.DEPTNO) AS t4\n" + + " FULL JOIN (SELECT CAST(DEPTNO AS INTEGER) AS DEPTNO0, " + + "COLLECT(ROW(DEPTNO, DNAME, LOC)) AS C\n" + " FROM scott.DEPT\n" + " WHERE DEPTNO >= 20\n" - + " GROUP BY CAST(DEPTNO AS INTEGER)) AS t7 ON t4.DEPTNO = t7.DEPTNO\n" + + " GROUP BY CAST(DEPTNO AS INTEGER)) AS t8 ON t4.DEPTNO = t8.DEPTNO0\n" + "ORDER BY 1"; pig(script).assertRel(hasTree(plan)) .assertResult(is(result))