Skip to content

Commit

Permalink
Support alias for UnPivot statement (see discussion #1374) (#1380)
Browse files Browse the repository at this point in the history
- Changed JSqlParserCC.jjt file to add the alias to the UnPivot lexical entity.
- Added Alias to the UnPivot object.
- Improved SelectDeParser to correctly deparse SubSelect's UnPivot component.
  • Loading branch information
fabriziodelfranco authored Oct 20, 2021
1 parent a8afd9a commit 0c0c32e
Show file tree
Hide file tree
Showing 4 changed files with 49 additions and 2 deletions.
13 changes: 12 additions & 1 deletion src/main/java/net/sf/jsqlparser/statement/select/UnPivot.java
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@
*/
package net.sf.jsqlparser.statement.select;

import net.sf.jsqlparser.expression.Alias;
import net.sf.jsqlparser.schema.Column;

import java.util.List;
Expand All @@ -20,6 +21,7 @@ public class UnPivot {
private Column unpivotClause;
private List<Column> unpivotForClause;
private List<SelectExpressionItem> unpivotInClause;
private Alias alias;

public void accept(PivotVisitor pivotVisitor) {
pivotVisitor.visit(this);
Expand Down Expand Up @@ -69,11 +71,20 @@ public String toString() {
+ (includeNullsSpecified && !includeNulls ? " EXCLUDE NULLS" : "")
+ " (" + unpivotClause
+ " FOR " + PlainSelect.getStringList(unpivotForClause, true, unpivotForClause != null && unpivotForClause.size() > 1)
+ " IN " + PlainSelect.getStringList(unpivotInClause, true, true) + ")";
+ " IN " + PlainSelect.getStringList(unpivotInClause, true, true) + ")"
+ (alias!=null ? alias.toString() : "");
}

public UnPivot withIncludeNulls(boolean includeNulls) {
this.setIncludeNulls(includeNulls);
return this;
}

public Alias getAlias() {
return alias;
}

public void setAlias(Alias alias) {
this.alias = alias;
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -253,12 +253,17 @@ public void visit(SubSelect subSelect) {
buffer.append(subSelect.isUseBrackets() ? ")" : "");
Alias alias = subSelect.getAlias();
if (alias != null) {
buffer.append(alias.toString());
buffer.append(alias);
}
Pivot pivot = subSelect.getPivot();
if (pivot != null) {
pivot.accept(this);
}

UnPivot unPivot = subSelect.getUnPivot();
if (unPivot != null) {
unPivot.accept(this);
}
}

@Override
Expand Down Expand Up @@ -308,6 +313,9 @@ public void visit(UnPivot unpivot) {
.append(PlainSelect.getStringList(unpivotForClause, true,
unpivotForClause != null && unpivotForClause.size() > 1))
.append(" IN ").append(PlainSelect.getStringList(unpivot.getUnPivotInClause(), true, true)).append(")");
if (unpivot.getAlias() != null) {
buffer.append(unpivot.getAlias().toString());
}
}

@Override
Expand Down
3 changes: 3 additions & 0 deletions src/main/jjtree/net/sf/jsqlparser/parser/JSqlParserCC.jjt
Original file line number Diff line number Diff line change
Expand Up @@ -2273,6 +2273,7 @@ UnPivot UnPivot():
Column unpivotClause;
List<Column> unpivotForClause;
List<SelectExpressionItem> unpivotInClause;
Alias alias = null;
}
{
<K_UNPIVOT>
Expand All @@ -2284,10 +2285,12 @@ UnPivot UnPivot():
unpivotInClause = PivotSingleInItems()
")"
")"
[ alias = Alias() ]
{
retval.setUnPivotClause(unpivotClause);
retval.setUnPivotForClause(unpivotForClause);
retval.setUnPivotInClause(unpivotInClause);
retval.setAlias(alias);
return retval;
}
}
Expand Down
25 changes: 25 additions & 0 deletions src/test/java/net/sf/jsqlparser/statement/select/SelectTest.java
Original file line number Diff line number Diff line change
Expand Up @@ -2516,6 +2516,31 @@ public void testPivotFunction() throws JSQLParserException {
assertSqlCanBeParsedAndDeparsed("SELECT to_char((SELECT col1 FROM (SELECT times_purchased, state_code FROM customers t) PIVOT (count(state_code) FOR state_code IN ('NY', 'CT', 'NJ', 'FL', 'MO')) ORDER BY times_purchased)) FROM DUAL");
}

@Test
public void testUnPivotWithAlias() throws JSQLParserException {
assertSqlCanBeParsedAndDeparsed("SELECT simulation_id, un_piv_alias.signal, un_piv_alias.val AS value FROM" +
" (SELECT simulation_id," +
" convert(numeric(18, 2), sum(convert(int, init_on))) DosingOnStatus_TenMinutes_sim," +
" convert(numeric(18, 2), sum(CASE WHEN pump_status = 0 THEN 10 ELSE 0 END)) AS DosingOffDurationHour_Hour_sim" +
" FROM ft_simulation_result" +
" WHERE simulation_id = 210 AND data_timestamp BETWEEN convert(datetime, '2021-09-14', 120) AND convert(datetime, '2021-09-18', 120)" +
" GROUP BY simulation_id) sim_data" +
" UNPIVOT" +
" (" +
"val" +
" FOR signal IN (DosingOnStatus_TenMinutes_sim, DosingOnDuration_Hour_sim)" +
") un_piv_alias");
}

@Test
public void testUnPivot() throws JSQLParserException {
String stmt = "SELECT * FROM sale_stats" +
" UNPIVOT (" +
"quantity" +
" FOR product_code IN (product_a AS 'A', product_b AS 'B', product_c AS 'C'))";
assertSqlCanBeParsedAndDeparsed(stmt);
}

@Test
public void testPivotWithAlias() throws JSQLParserException {
assertSqlCanBeParsedAndDeparsed("SELECT * FROM (SELECT * FROM mytable LEFT JOIN mytable2 ON Factor_ID = Id) f PIVOT (max(f.value) FOR f.factoryCode IN (ZD, COD, SW, PH))");
Expand Down

0 comments on commit 0c0c32e

Please sign in to comment.