Skip to content

Commit c2d84f5

Browse files
authored
Support for Snowflake dynamic pivot (#1280)
1 parent 792e389 commit c2d84f5

File tree

5 files changed

+138
-15
lines changed

5 files changed

+138
-15
lines changed

src/ast/mod.rs

Lines changed: 5 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -46,10 +46,11 @@ pub use self::query::{
4646
GroupByExpr, IdentWithAlias, IlikeSelectItem, Join, JoinConstraint, JoinOperator,
4747
JsonTableColumn, JsonTableColumnErrorHandling, LateralView, LockClause, LockType,
4848
MatchRecognizePattern, MatchRecognizeSymbol, Measure, NamedWindowDefinition, NamedWindowExpr,
49-
NonBlock, Offset, OffsetRows, OrderByExpr, Query, RenameSelectItem, RepetitionQuantifier,
50-
ReplaceSelectElement, ReplaceSelectItem, RowsPerMatch, Select, SelectInto, SelectItem, SetExpr,
51-
SetOperator, SetQuantifier, SymbolDefinition, Table, TableAlias, TableFactor, TableVersion,
52-
TableWithJoins, Top, TopQuantity, ValueTableMode, Values, WildcardAdditionalOptions, With,
49+
NonBlock, Offset, OffsetRows, OrderByExpr, PivotValueSource, Query, RenameSelectItem,
50+
RepetitionQuantifier, ReplaceSelectElement, ReplaceSelectItem, RowsPerMatch, Select,
51+
SelectInto, SelectItem, SetExpr, SetOperator, SetQuantifier, SymbolDefinition, Table,
52+
TableAlias, TableFactor, TableVersion, TableWithJoins, Top, TopQuantity, ValueTableMode,
53+
Values, WildcardAdditionalOptions, With,
5354
};
5455
pub use self::value::{
5556
escape_double_quote_string, escape_quoted_string, DateTimeField, DollarQuotedString,

src/ast/query.rs

Lines changed: 44 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -957,7 +957,8 @@ pub enum TableFactor {
957957
table: Box<TableFactor>,
958958
aggregate_functions: Vec<ExprWithAlias>, // Function expression
959959
value_column: Vec<Ident>,
960-
pivot_values: Vec<ExprWithAlias>,
960+
value_source: PivotValueSource,
961+
default_on_null: Option<Expr>,
961962
alias: Option<TableAlias>,
962963
},
963964
/// An UNPIVOT operation on a table.
@@ -998,6 +999,41 @@ pub enum TableFactor {
998999
},
9991000
}
10001001

1002+
/// The source of values in a `PIVOT` operation.
1003+
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
1004+
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
1005+
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
1006+
pub enum PivotValueSource {
1007+
/// Pivot on a static list of values.
1008+
///
1009+
/// See <https://docs.snowflake.com/en/sql-reference/constructs/pivot#pivot-on-a-specified-list-of-column-values-for-the-pivot-column>.
1010+
List(Vec<ExprWithAlias>),
1011+
/// Pivot on all distinct values of the pivot column.
1012+
///
1013+
/// See <https://docs.snowflake.com/en/sql-reference/constructs/pivot#pivot-on-all-distinct-column-values-automatically-with-dynamic-pivot>.
1014+
Any(Vec<OrderByExpr>),
1015+
/// Pivot on all values returned by a subquery.
1016+
///
1017+
/// See <https://docs.snowflake.com/en/sql-reference/constructs/pivot#pivot-on-column-values-using-a-subquery-with-dynamic-pivot>.
1018+
Subquery(Query),
1019+
}
1020+
1021+
impl fmt::Display for PivotValueSource {
1022+
fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
1023+
match self {
1024+
PivotValueSource::List(values) => write!(f, "{}", display_comma_separated(values)),
1025+
PivotValueSource::Any(order_by) => {
1026+
write!(f, "ANY")?;
1027+
if !order_by.is_empty() {
1028+
write!(f, " ORDER BY {}", display_comma_separated(order_by))?;
1029+
}
1030+
Ok(())
1031+
}
1032+
PivotValueSource::Subquery(query) => write!(f, "{query}"),
1033+
}
1034+
}
1035+
}
1036+
10011037
/// An item in the `MEASURES` subclause of a `MATCH_RECOGNIZE` operation.
10021038
///
10031039
/// See <https://docs.snowflake.com/en/sql-reference/constructs/match_recognize#measures-specifying-additional-output-columns>.
@@ -1324,17 +1360,20 @@ impl fmt::Display for TableFactor {
13241360
table,
13251361
aggregate_functions,
13261362
value_column,
1327-
pivot_values,
1363+
value_source,
1364+
default_on_null,
13281365
alias,
13291366
} => {
13301367
write!(
13311368
f,
1332-
"{} PIVOT({} FOR {} IN ({}))",
1333-
table,
1369+
"{table} PIVOT({} FOR {} IN ({value_source})",
13341370
display_comma_separated(aggregate_functions),
13351371
Expr::CompoundIdentifier(value_column.to_vec()),
1336-
display_comma_separated(pivot_values)
13371372
)?;
1373+
if let Some(expr) = default_on_null {
1374+
write!(f, " DEFAULT ON NULL ({expr})")?;
1375+
}
1376+
write!(f, ")")?;
13381377
if alias.is_some() {
13391378
write!(f, " AS {}", alias.as_ref().unwrap())?;
13401379
}

src/parser/mod.rs

Lines changed: 30 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -9191,16 +9191,44 @@ impl<'a> Parser<'a> {
91919191
self.expect_keyword(Keyword::FOR)?;
91929192
let value_column = self.parse_object_name(false)?.0;
91939193
self.expect_keyword(Keyword::IN)?;
9194+
91949195
self.expect_token(&Token::LParen)?;
9195-
let pivot_values = self.parse_comma_separated(Self::parse_expr_with_alias)?;
9196+
let value_source = if self.parse_keyword(Keyword::ANY) {
9197+
let order_by = if self.parse_keywords(&[Keyword::ORDER, Keyword::BY]) {
9198+
self.parse_comma_separated(Parser::parse_order_by_expr)?
9199+
} else {
9200+
vec![]
9201+
};
9202+
PivotValueSource::Any(order_by)
9203+
} else if self
9204+
.parse_one_of_keywords(&[Keyword::SELECT, Keyword::WITH])
9205+
.is_some()
9206+
{
9207+
self.prev_token();
9208+
PivotValueSource::Subquery(self.parse_query()?)
9209+
} else {
9210+
PivotValueSource::List(self.parse_comma_separated(Self::parse_expr_with_alias)?)
9211+
};
91969212
self.expect_token(&Token::RParen)?;
9213+
9214+
let default_on_null =
9215+
if self.parse_keywords(&[Keyword::DEFAULT, Keyword::ON, Keyword::NULL]) {
9216+
self.expect_token(&Token::LParen)?;
9217+
let expr = self.parse_expr()?;
9218+
self.expect_token(&Token::RParen)?;
9219+
Some(expr)
9220+
} else {
9221+
None
9222+
};
9223+
91979224
self.expect_token(&Token::RParen)?;
91989225
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
91999226
Ok(TableFactor::Pivot {
92009227
table: Box::new(table),
92019228
aggregate_functions,
92029229
value_column,
9203-
pivot_values,
9230+
value_source,
9231+
default_on_null,
92049232
alias,
92059233
})
92069234
}

tests/sqlparser_common.rs

Lines changed: 6 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -8618,7 +8618,7 @@ fn parse_pivot_table() {
86188618
expected_function("c", Some("u")),
86198619
],
86208620
value_column: vec![Ident::new("a"), Ident::new("MONTH")],
8621-
pivot_values: vec![
8621+
value_source: PivotValueSource::List(vec![
86228622
ExprWithAlias {
86238623
expr: Expr::Value(number("1")),
86248624
alias: Some(Ident::new("x"))
@@ -8631,7 +8631,8 @@ fn parse_pivot_table() {
86318631
expr: Expr::Identifier(Ident::new("three")),
86328632
alias: Some(Ident::new("y"))
86338633
},
8634-
],
8634+
]),
8635+
default_on_null: None,
86358636
alias: Some(TableAlias {
86368637
name: Ident {
86378638
value: "p".to_string(),
@@ -8769,7 +8770,7 @@ fn parse_pivot_unpivot_table() {
87698770
alias: None
87708771
}],
87718772
value_column: vec![Ident::new("year")],
8772-
pivot_values: vec![
8773+
value_source: PivotValueSource::List(vec![
87738774
ExprWithAlias {
87748775
expr: Expr::Value(Value::SingleQuotedString("population_2000".to_string())),
87758776
alias: None
@@ -8778,7 +8779,8 @@ fn parse_pivot_unpivot_table() {
87788779
expr: Expr::Value(Value::SingleQuotedString("population_2010".to_string())),
87798780
alias: None
87808781
},
8781-
],
8782+
]),
8783+
default_on_null: None,
87828784
alias: Some(TableAlias {
87838785
name: Ident::new("p"),
87848786
columns: vec![]

tests/sqlparser_snowflake.rs

Lines changed: 53 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1585,3 +1585,56 @@ fn first_value_ignore_nulls() {
15851585
"FROM some_table"
15861586
));
15871587
}
1588+
1589+
#[test]
1590+
fn test_pivot() {
1591+
// pivot on static list of values with default
1592+
#[rustfmt::skip]
1593+
snowflake().verified_only_select(concat!(
1594+
"SELECT * ",
1595+
"FROM quarterly_sales ",
1596+
"PIVOT(SUM(amount) ",
1597+
"FOR quarter IN (",
1598+
"'2023_Q1', ",
1599+
"'2023_Q2', ",
1600+
"'2023_Q3', ",
1601+
"'2023_Q4', ",
1602+
"'2024_Q1') ",
1603+
"DEFAULT ON NULL (0)",
1604+
") ",
1605+
"ORDER BY empid",
1606+
));
1607+
1608+
// dynamic pivot from subquery
1609+
#[rustfmt::skip]
1610+
snowflake().verified_only_select(concat!(
1611+
"SELECT * ",
1612+
"FROM quarterly_sales ",
1613+
"PIVOT(SUM(amount) FOR quarter IN (",
1614+
"SELECT DISTINCT quarter ",
1615+
"FROM ad_campaign_types_by_quarter ",
1616+
"WHERE television = true ",
1617+
"ORDER BY quarter)",
1618+
") ",
1619+
"ORDER BY empid",
1620+
));
1621+
1622+
// dynamic pivot on any value (with order by)
1623+
#[rustfmt::skip]
1624+
snowflake().verified_only_select(concat!(
1625+
"SELECT * ",
1626+
"FROM quarterly_sales ",
1627+
"PIVOT(SUM(amount) FOR quarter IN (ANY ORDER BY quarter)) ",
1628+
"ORDER BY empid",
1629+
));
1630+
1631+
// dynamic pivot on any value (without order by)
1632+
#[rustfmt::skip]
1633+
snowflake().verified_only_select(concat!(
1634+
"SELECT * ",
1635+
"FROM sales_data ",
1636+
"PIVOT(SUM(total_sales) FOR fis_quarter IN (ANY)) ",
1637+
"WHERE fis_year IN (2023) ",
1638+
"ORDER BY region",
1639+
));
1640+
}

0 commit comments

Comments
 (0)