Skip to content

Commit

Permalink
[CALCITE-5126] Implicit column alias for single-column UNNEST should …
Browse files Browse the repository at this point in the history
…work with any single-column UNNEST’s input

Close #2789
  • Loading branch information
dssysolyatin authored and julianhyde committed Aug 24, 2022
1 parent 7de37ae commit e2f949d
Show file tree
Hide file tree
Showing 6 changed files with 65 additions and 21 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -19,10 +19,13 @@
import org.apache.calcite.rel.type.RelDataType;
import org.apache.calcite.rel.type.RelDataTypeFactoryImpl;
import org.apache.calcite.rel.type.RelDataTypeField;
import org.apache.calcite.sql.SqlBasicCall;
import org.apache.calcite.sql.SqlCall;
import org.apache.calcite.sql.SqlIdentifier;
import org.apache.calcite.sql.SqlKind;
import org.apache.calcite.sql.SqlNode;
import org.apache.calcite.sql.SqlNodeList;
import org.apache.calcite.sql.SqlUnnestOperator;
import org.apache.calcite.sql.fun.SqlStdOperatorTable;
import org.apache.calcite.sql.parser.SqlParserPos;
import org.apache.calcite.util.Pair;
Expand Down Expand Up @@ -81,6 +84,7 @@ protected AliasNamespace(
final RelDataType rowType = childNs.getRowTypeSansSystemColumns();
final RelDataType aliasedType;
if (operands.size() == 2) {
final SqlNode node = operands.get(0);
// Alias is 'AS t' (no column list).
// If the sub-query is UNNEST or VALUES,
// and the sub-query has one column,
Expand All @@ -91,6 +95,17 @@ protected AliasNamespace(
.add(((SqlIdentifier) operands.get(1)).getSimple(),
rowType.getFieldList().get(0).getType())
.build();
// If the sub-query is UNNEST with ordinality
// and the sub-query has two columns: data column, ordinality column
// then the namespace's sole column is named after the alias.
} else if (node.getKind() == SqlKind.UNNEST && rowType.getFieldCount() == 2
&& ((SqlUnnestOperator) ((SqlBasicCall) node).getOperator()).withOrdinality) {
aliasedType = validator.getTypeFactory().builder()
.kind(rowType.getStructKind())
.add(((SqlIdentifier) operands.get(1)).getSimple(),
rowType.getFieldList().get(0).getType())
.add(rowType.getFieldList().get(1))
.build();
} else {
aliasedType = rowType;
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2333,18 +2333,14 @@ private SqlNode registerFrom(
alias = String.valueOf(call.operand(1));
}
expr = call.operand(0);
final boolean needAlias = call.operandCount() > 2
final boolean needAliasNamespace = call.operandCount() > 2
|| expr.getKind() == SqlKind.VALUES
|| expr.getKind() == SqlKind.UNNEST
&& (((SqlCall) expr).operand(0).getKind()
== SqlKind.ARRAY_VALUE_CONSTRUCTOR
|| ((SqlCall) expr).operand(0).getKind()
== SqlKind.MULTISET_VALUE_CONSTRUCTOR);
|| expr.getKind() == SqlKind.UNNEST;
newExpr =
registerFrom(
parentScope,
usingScope,
!needAlias,
!needAliasNamespace,
expr,
enclosingNode,
alias,
Expand All @@ -2357,7 +2353,7 @@ private SqlNode registerFrom(

// If alias has a column list, introduce a namespace to translate
// column names. We skipped registering it just now.
if (needAlias) {
if (needAliasNamespace) {
registerNamespace(
usingScope,
alias,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -3640,15 +3640,15 @@ void checkCorrelatedMapSubQuery(boolean expand) {
@Test void testDynamicSchemaUnnest() {
final String sql = "select t1.c_nationkey, t3.fake_col3\n"
+ "from SALES.CUSTOMER as t1,\n"
+ "lateral (select t2.\"$unnest\" as fake_col3\n"
+ "lateral (select t2 as fake_col3\n"
+ " from unnest(t1.fake_col) as t2) as t3";
sql(sql).withDynamicTable().ok();
}

@Test void testStarDynamicSchemaUnnest() {
final String sql = "select *\n"
+ "from SALES.CUSTOMER as t1,\n"
+ "lateral (select t2.\"$unnest\" as fake_col3\n"
+ "lateral (select t2 as fake_col3\n"
+ " from unnest(t1.fake_col) as t2) as t3";
sql(sql).withDynamicTable().ok();
}
Expand Down
12 changes: 11 additions & 1 deletion core/src/test/java/org/apache/calcite/test/SqlValidatorTest.java
Original file line number Diff line number Diff line change
Expand Up @@ -8295,6 +8295,8 @@ public void _testGroupExpressionEquivalenceParams() {
.type("RecordType(INTEGER NOT NULL EXPR$0, INTEGER NOT NULL ORDINALITY) NOT NULL");
sql("select*from unnest(array[43.2e1, cast(null as decimal(4,2))]) with ordinality")
.type("RecordType(DOUBLE EXPR$0, INTEGER NOT NULL ORDINALITY) NOT NULL");
sql("select * from unnest(array(select deptno from dept)) with ordinality as t")
.type("RecordType(INTEGER NOT NULL T, INTEGER NOT NULL ORDINALITY) NOT NULL");
sql("select*from ^unnest(1) with ordinality^")
.fails("(?s).*Cannot apply 'UNNEST' to arguments of type 'UNNEST.<INTEGER>.'.*");
sql("select deptno\n"
Expand Down Expand Up @@ -8338,6 +8340,10 @@ public void _testGroupExpressionEquivalenceParams() {
// relation, that alias becomes the name of the column.
sql("select fruit.* from UNNEST(array ['apple', 'banana']) as fruit")
.type(expectedType);
sql("select fruit.* from UNNEST(array(select 'banana')) as fruit")
.type(expectedType);
sql("SELECT array(SELECT y + 1 FROM UNNEST(s.x) y) FROM (SELECT ARRAY[1,2,3] as x) s")
.ok();

// The magic doesn't happen if the query is not an UNNEST.
// In this case, the query is a SELECT.
Expand All @@ -8350,14 +8356,18 @@ public void _testGroupExpressionEquivalenceParams() {
sql("select * from UNNEST(array [('apple', 1), ('banana', 2)]) as fruit")
.type("RecordType(CHAR(6) NOT NULL EXPR$0, INTEGER NOT NULL EXPR$1) "
+ "NOT NULL");

// VALUES gets the same treatment as ARRAY. (Unlike PostgreSQL.)
sql("select * from (values ('apple'), ('banana')) as fruit")
.type("RecordType(CHAR(6) NOT NULL FRUIT) NOT NULL");

// UNNEST MULTISET gets the same treatment as UNNEST ARRAY.
sql("select * from unnest(multiset [1, 2, 1]) as f")
.type("RecordType(INTEGER NOT NULL F) NOT NULL");

// The magic doesn't happen if the UNNEST is used without AS operator.
sql("select * from (SELECT ARRAY['banana'] as fruits) as t, UNNEST(t.fruits)")
.type("RecordType(CHAR(6) NOT NULL ARRAY NOT NULL FRUITS, "
+ "CHAR(6) NOT NULL EXPR$0) NOT NULL").ok();
}

@Test void testCorrelationJoin() {
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -6427,7 +6427,7 @@ unnest(t1.fake_col) as t2]]>
</Resource>
<Resource name="plan">
<![CDATA[
LogicalProject(**=[$1], $unnest=[$2])
LogicalProject(**=[$1], T2=[$2])
LogicalCorrelate(correlation=[$cor0], joinType=[inner], requiredColumns=[{0}])
LogicalTableScan(table=[[CATALOG, SALES, CUSTOMER]])
Uncollect
Expand Down
41 changes: 32 additions & 9 deletions core/src/test/resources/sql/unnest.iq
Original file line number Diff line number Diff line change
Expand Up @@ -105,6 +105,31 @@ from UNNEST(array ['apple', 'banana']) as "fruit";

!ok

select fruit
from UNNEST(array(select 'banana')) as fruit;
+--------+
| FRUIT |
+--------+
| banana |
+--------+
(1 row)

!ok

#TODO: Remove if when [CALCITE-5127] will be fixed.
!if (false) {
SELECT ARRAY(SELECT y + 1 FROM UNNEST(s.x) y)
FROM (SELECT ARRAY[1,2,3] as x) s;
+--------+
| FRUIT |
+--------+
| banana |
+--------+
(1 row)

!ok
!}

# If UNNEST is not the direct child of the AS, aliasing doesn't happen.
SELECT fruit.*
FROM (
Expand All @@ -120,21 +145,19 @@ FROM (

!ok

# If UNNEST applies to a value that is not an array constructor,
# aliasing doesn't happen. Thus the last column is 'EXPR$0', not 'z'.
SELECT *
FROM (
SELECT x, collect(y) as ys
FROM (VALUES (1, 1), (2, 2), (1, 3)) AS t (x, y)
GROUP BY x) AS u,
UNNEST(u.ys) AS z;
+---+--------+--------+
| X | YS | EXPR$0 |
+---+--------+--------+
| 1 | [1, 3] | 1 |
| 1 | [1, 3] | 3 |
| 2 | [2] | 2 |
+---+--------+--------+
+---+--------+---+
| X | YS | Z |
+---+--------+---+
| 1 | [1, 3] | 1 |
| 1 | [1, 3] | 3 |
| 2 | [2] | 2 |
+---+--------+---+
(3 rows)

!ok
Expand Down

0 comments on commit e2f949d

Please sign in to comment.