Skip to content

Commit

Permalink
[CALCITE-5510] RelToSqlConverter should use ordinal for ORDER BY if…
Browse files Browse the repository at this point in the history
… the dialect allows

Close apache#3057
  • Loading branch information
wangpeng authored and libenchao committed Feb 25, 2023
1 parent 29fcbf1 commit a990ecc
Show file tree
Hide file tree
Showing 3 changed files with 80 additions and 12 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -615,6 +615,13 @@ public SqlNode orderField(int ordinal) {
final String strValue = ((SqlNumericLiteral) node).toValue();
return SqlLiteral.createCharString(strValue, node.getParserPosition());
}
if (node instanceof SqlCall
&& dialect.getConformance().isSortByOrdinal()) {
// If the field is expression and sort by ordinal is set in dialect,
// convert it to ordinal.
return SqlLiteral.createExactNumeric(
Integer.toString(ordinal + 1), SqlParserPos.ZERO);
}
return node;
}

Expand Down Expand Up @@ -1809,6 +1816,13 @@ private boolean needNewSubQuery(
return true;
}

if (rel instanceof Project
&& clauses.contains(Clause.ORDER_BY)
&& dialect.getConformance().isSortByOrdinal()) {
// Cannot merge a Project that contains sort by ordinal under it.
return hasSortByOrdinal();
}

if (rel instanceof Aggregate) {
final Aggregate agg = (Aggregate) rel;
final boolean hasNestedAgg =
Expand All @@ -1829,6 +1843,30 @@ private boolean needNewSubQuery(
return false;
}

/**
* Return whether the current {@link SqlNode} in {@link Result} contains sort by column
* in ordinal format.
*/
private boolean hasSortByOrdinal(@UnknownInitialization Result this) {
if (node instanceof SqlSelect) {
final SqlNodeList orderList = ((SqlSelect) node).getOrderList();
if (orderList == null) {
return false;
}
for (SqlNode sqlNode : orderList) {
if (!(sqlNode instanceof SqlBasicCall)) {
return false;
}
for (SqlNode operand : ((SqlBasicCall) sqlNode).getOperandList()) {
if (operand instanceof SqlNumericLiteral) {
return true;
}
}
}
}
return false;
}

/** Returns whether an {@link Aggregate} contains nested operands that
* match the predicate.
*
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -61,6 +61,7 @@
import org.apache.calcite.sql.dialect.MysqlSqlDialect;
import org.apache.calcite.sql.dialect.OracleSqlDialect;
import org.apache.calcite.sql.dialect.PostgresqlSqlDialect;
import org.apache.calcite.sql.dialect.PrestoSqlDialect;
import org.apache.calcite.sql.fun.SqlLibrary;
import org.apache.calcite.sql.fun.SqlStdOperatorTable;
import org.apache.calcite.sql.parser.SqlParser;
Expand Down Expand Up @@ -626,7 +627,7 @@ private static String toSql(RelNode root, SqlDialect dialect,
+ "GROUP BY GROUPING SETS((\"EMPNO\", \"ENAME\", \"JOB\"),"
+ " (\"EMPNO\", \"ENAME\"), \"EMPNO\")\n"
+ "HAVING GROUPING(\"EMPNO\", \"ENAME\", \"JOB\") <> 0\n"
+ "ORDER BY COUNT(*)";
+ "ORDER BY 4";
relFn(relFn).ok(expectedSql);
}

Expand Down Expand Up @@ -761,17 +762,17 @@ private static String toSql(RelNode root, SqlDialect dialect,
final String expected = "SELECT \"product_class_id\", COUNT(*) AS \"C\"\n"
+ "FROM \"foodmart\".\"product\"\n"
+ "GROUP BY ROLLUP(\"product_class_id\")\n"
+ "ORDER BY \"product_class_id\", COUNT(*)";
+ "ORDER BY \"product_class_id\", 2";
final String expectedMysql = "SELECT `product_class_id`, COUNT(*) AS `C`\n"
+ "FROM `foodmart`.`product`\n"
+ "GROUP BY `product_class_id` WITH ROLLUP\n"
+ "ORDER BY `product_class_id` IS NULL, `product_class_id`,"
+ " COUNT(*) IS NULL, COUNT(*)";
+ " COUNT(*) IS NULL, 2";
final String expectedPresto = "SELECT \"product_class_id\", COUNT(*) AS \"C\"\n"
+ "FROM \"foodmart\".\"product\"\n"
+ "GROUP BY ROLLUP(\"product_class_id\")\n"
+ "ORDER BY \"product_class_id\" IS NULL, \"product_class_id\", "
+ "COUNT(*) IS NULL, COUNT(*)";
+ "COUNT(*) IS NULL, 2";
sql(query)
.ok(expected)
.withMysql().ok(expectedMysql)
Expand Down Expand Up @@ -811,14 +812,14 @@ private static String toSql(RelNode root, SqlDialect dialect,
+ " COUNT(*) AS \"C\"\n"
+ "FROM \"foodmart\".\"product\"\n"
+ "GROUP BY ROLLUP(\"product_class_id\", \"brand_name\")\n"
+ "ORDER BY \"product_class_id\", \"brand_name\", COUNT(*)";
+ "ORDER BY \"product_class_id\", \"brand_name\", 3";
final String expectedMysql = "SELECT `product_class_id`, `brand_name`,"
+ " COUNT(*) AS `C`\n"
+ "FROM `foodmart`.`product`\n"
+ "GROUP BY `product_class_id`, `brand_name` WITH ROLLUP\n"
+ "ORDER BY `product_class_id` IS NULL, `product_class_id`,"
+ " `brand_name` IS NULL, `brand_name`,"
+ " COUNT(*) IS NULL, COUNT(*)";
+ " COUNT(*) IS NULL, 3";
sql(query)
.ok(expected)
.withMysql().ok(expectedMysql);
Expand Down Expand Up @@ -1758,6 +1759,35 @@ private SqlDialect nonOrdinalDialect() {
+ "FROM \"foodmart\".\"employee\"");
}

/** Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-5510">[CALCITE-5510]
* RelToSqlConverter don't support sort by ordinal when sort by column is an expression</a>.
*/
@Test void testOrderByOrdinalWithExpression() {
final String query = "select \"product_id\", count(*) as \"c\"\n"
+ "from \"product\"\n"
+ "group by \"product_id\"\n"
+ "order by 2";
final String ordinalExpected = "SELECT \"product_id\", COUNT(*) AS \"c\"\n"
+ "FROM \"foodmart\".\"product\"\n"
+ "GROUP BY \"product_id\"\n"
+ "ORDER BY 2";
final String nonOrdinalExpected = "SELECT product_id, COUNT(*) AS c\n"
+ "FROM foodmart.product\n"
+ "GROUP BY product_id\n"
+ "ORDER BY COUNT(*)";
final String prestoExpected = "SELECT \"product_id\", COUNT(*) AS \"c\"\n"
+ "FROM \"foodmart\".\"product\"\n"
+ "GROUP BY \"product_id\"\n"
+ "ORDER BY COUNT(*) IS NULL, 2";
sql(query)
.ok(ordinalExpected)
.dialect(nonOrdinalDialect())
.ok(nonOrdinalExpected)
.dialect(PrestoSqlDialect.DEFAULT)
.ok(prestoExpected);
}

/** Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-3440">[CALCITE-3440]
* RelToSqlConverter does not properly alias ambiguous ORDER BY</a>. */
Expand Down Expand Up @@ -6691,7 +6721,7 @@ private void checkLiteral2(String expression, String expected) {
+ "FROM SCOTT.EMP\n"
+ "GROUP BY DEPTNO\n"
+ "HAVING COUNT(DISTINCT EMPNO) > 0\n"
+ "ORDER BY COUNT(DISTINCT EMPNO) IS NULL DESC, COUNT(DISTINCT EMPNO) DESC";
+ "ORDER BY COUNT(DISTINCT EMPNO) IS NULL DESC, 2 DESC";

// Convert rel node to SQL with BigQuery dialect,
// in which "isHavingAlias" is true.
Expand Down
10 changes: 5 additions & 5 deletions piglet/src/test/java/org/apache/calcite/test/PigRelOpTest.java
Original file line number Diff line number Diff line change
Expand Up @@ -1362,7 +1362,7 @@ private Fluent pig(String script) {
+ "BIGINT) AS $f1, CAST(SUM(SAL) AS DECIMAL(19, 0)) AS salSum\n"
+ "FROM scott.EMP\n"
+ "GROUP BY DEPTNO, MGR, HIREDATE\n"
+ "ORDER BY CAST(SUM(SAL) AS DECIMAL(19, 0))";
+ "ORDER BY 3";
pig(script).assertResult(is(result))
.assertSql(is(sql));
}
Expand Down Expand Up @@ -1480,7 +1480,7 @@ private Fluent pig(String script) {
+ "(19, 0)) AS salAvg\n"
+ "FROM scott.EMP\n"
+ "GROUP BY DEPTNO, MGR, HIREDATE\n"
+ "ORDER BY CAST(SUM(SAL) AS DECIMAL(19, 0))";
+ "ORDER BY 3";
pig(script).assertRel(hasTree(plan))
.assertOptimizedRel(hasTree(optimizedPlan))
.assertResult(is(result))
Expand All @@ -1501,7 +1501,7 @@ private Fluent pig(String script) {
+ "AS A\n"
+ "FROM scott.EMP\n"
+ "GROUP BY DEPTNO, MGR, HIREDATE\n"
+ "ORDER BY CAST(SUM(SAL) AS DECIMAL(19, 0))";
+ "ORDER BY 3";
pig(script2).assertSql(is(sql2));

final String script3 = ""
Expand Down Expand Up @@ -1551,7 +1551,7 @@ private Fluent pig(String script) {
+ "COLLECT(COMM) AS comArray, CAST(SUM(SAL) AS DECIMAL(19, 0)) AS salSum\n"
+ "FROM scott.EMP\n"
+ "GROUP BY DEPTNO, MGR, HIREDATE\n"
+ "ORDER BY CAST(SUM(SAL) AS DECIMAL(19, 0))";
+ "ORDER BY 7";
pig(script).assertRel(hasTree(plan))
.assertOptimizedRel(hasTree(optimizedPlan))
.assertSql(is(sql));
Expand Down Expand Up @@ -1610,7 +1610,7 @@ private Fluent pig(String script) {
+ " FROM scott.DEPT\n"
+ " WHERE DEPTNO >= 20\n"
+ " GROUP BY CAST(DEPTNO AS INTEGER)) AS t7 ON t4.DEPTNO = t7.DEPTNO\n"
+ "ORDER BY CASE WHEN t4.DEPTNO IS NOT NULL THEN t4.DEPTNO ELSE t7.DEPTNO END";
+ "ORDER BY 1";
pig(script).assertRel(hasTree(plan))
.assertResult(is(result))
.assertSql(is(sql));
Expand Down

0 comments on commit a990ecc

Please sign in to comment.