Skip to content

Commit 883c7c0

Browse files
support PIVOT table syntax
Signed-off-by: Pawel Leszczynski <[email protected]>
1 parent 4ff3aeb commit 883c7c0

File tree

4 files changed

+146
-0
lines changed

4 files changed

+146
-0
lines changed

src/ast/query.rs

+42
Original file line numberDiff line numberDiff line change
@@ -670,6 +670,18 @@ pub enum TableFactor {
670670
table_with_joins: Box<TableWithJoins>,
671671
alias: Option<TableAlias>,
672672
},
673+
/// Represents PIVOT operation on a table.
674+
/// For example `FROM monthly_sales PIVOT(sum(amount) FOR MONTH IN ('JAN', 'FEB'))`
675+
/// See <https://docs.snowflake.com/en/sql-reference/constructs/pivot>
676+
Pivot {
677+
#[cfg_attr(feature = "visitor", visit(with = "visit_relation"))]
678+
name: ObjectName,
679+
table_alias: Option<TableAlias>,
680+
aggregate_function: Expr, // Function expression
681+
value_column: Vec<Ident>,
682+
pivot_values: Vec<Value>,
683+
pivot_alias: Option<TableAlias>,
684+
},
673685
}
674686

675687
impl fmt::Display for TableFactor {
@@ -742,6 +754,36 @@ impl fmt::Display for TableFactor {
742754
}
743755
Ok(())
744756
}
757+
TableFactor::Pivot {
758+
name,
759+
table_alias,
760+
aggregate_function,
761+
value_column,
762+
pivot_values,
763+
pivot_alias,
764+
} => {
765+
write!(f, "{}", name)?;
766+
if table_alias.is_some() {
767+
write!(f, " AS {}", table_alias.as_ref().unwrap())?;
768+
}
769+
write!(
770+
f,
771+
" PIVOT({} FOR {} IN (",
772+
aggregate_function,
773+
Expr::CompoundIdentifier(value_column.to_vec())
774+
)?;
775+
for value in pivot_values {
776+
write!(f, "{}", value)?;
777+
if !value.eq(pivot_values.last().unwrap()) {
778+
write!(f, ", ")?;
779+
}
780+
}
781+
write!(f, "))")?;
782+
if pivot_alias.is_some() {
783+
write!(f, " AS {}", pivot_alias.as_ref().unwrap())?;
784+
}
785+
Ok(())
786+
}
745787
}
746788
}
747789
}

src/keywords.rs

+2
Original file line numberDiff line numberDiff line change
@@ -431,6 +431,7 @@ define_keywords!(
431431
PERCENTILE_DISC,
432432
PERCENT_RANK,
433433
PERIOD,
434+
PIVOT,
434435
PLACING,
435436
PLANS,
436437
PORTION,
@@ -647,6 +648,7 @@ pub const RESERVED_FOR_TABLE_ALIAS: &[Keyword] = &[
647648
Keyword::SORT,
648649
Keyword::HAVING,
649650
Keyword::ORDER,
651+
Keyword::PIVOT,
650652
Keyword::TOP,
651653
Keyword::LATERAL,
652654
Keyword::VIEW,

src/parser.rs

+40
Original file line numberDiff line numberDiff line change
@@ -5672,6 +5672,9 @@ impl<'a> Parser<'a> {
56725672
| TableFactor::Table { alias, .. }
56735673
| TableFactor::UNNEST { alias, .. }
56745674
| TableFactor::TableFunction { alias, .. }
5675+
| TableFactor::Pivot {
5676+
pivot_alias: alias, ..
5677+
}
56755678
| TableFactor::NestedJoin { alias, .. } => {
56765679
// but not `FROM (mytable AS alias1) AS alias2`.
56775680
if let Some(inner_alias) = alias {
@@ -5729,13 +5732,21 @@ impl<'a> Parser<'a> {
57295732
})
57305733
} else {
57315734
let name = self.parse_object_name()?;
5735+
57325736
// Postgres, MSSQL: table-valued functions:
57335737
let args = if self.consume_token(&Token::LParen) {
57345738
Some(self.parse_optional_args()?)
57355739
} else {
57365740
None
57375741
};
5742+
57385743
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
5744+
5745+
// Pivot
5746+
if self.parse_keyword(Keyword::PIVOT) {
5747+
return self.parse_pivot_table_factor(name, alias);
5748+
}
5749+
57395750
// MSSQL-specific table hints:
57405751
let mut with_hints = vec![];
57415752
if self.parse_keyword(Keyword::WITH) {
@@ -5773,6 +5784,35 @@ impl<'a> Parser<'a> {
57735784
})
57745785
}
57755786

5787+
pub fn parse_pivot_table_factor(
5788+
&mut self,
5789+
name: ObjectName,
5790+
table_alias: Option<TableAlias>,
5791+
) -> Result<TableFactor, ParserError> {
5792+
self.expect_token(&Token::LParen)?;
5793+
let function_name = match self.next_token().token {
5794+
Token::Word(w) => Ok(w.value),
5795+
_ => self.expected("an aggregate function name", self.peek_token()),
5796+
}?;
5797+
let function = self.parse_function(ObjectName(vec![Ident::new(function_name)]))?;
5798+
self.expect_keyword(Keyword::FOR)?;
5799+
let value_column = self.parse_object_name()?.0;
5800+
self.expect_keyword(Keyword::IN)?;
5801+
self.expect_token(&Token::LParen)?;
5802+
let pivot_values = self.parse_comma_separated(Parser::parse_value)?;
5803+
self.expect_token(&Token::RParen)?;
5804+
self.expect_token(&Token::RParen)?;
5805+
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
5806+
Ok(TableFactor::Pivot {
5807+
name,
5808+
table_alias,
5809+
aggregate_function: function,
5810+
value_column,
5811+
pivot_values,
5812+
pivot_alias: alias,
5813+
})
5814+
}
5815+
57765816
pub fn parse_join_constraint(&mut self, natural: bool) -> Result<JoinConstraint, ParserError> {
57775817
if natural {
57785818
Ok(JoinConstraint::Natural)

tests/sqlparser_common.rs

+62
Original file line numberDiff line numberDiff line change
@@ -21,6 +21,7 @@
2121
use matches::assert_matches;
2222

2323
use sqlparser::ast::SelectItem::UnnamedExpr;
24+
use sqlparser::ast::TableFactor::Pivot;
2425
use sqlparser::ast::*;
2526
use sqlparser::dialect::{
2627
AnsiDialect, BigQueryDialect, ClickHouseDialect, GenericDialect, HiveDialect, MsSqlDialect,
@@ -6718,6 +6719,67 @@ fn parse_with_recursion_limit() {
67186719
assert!(matches!(res, Ok(_)), "{res:?}");
67196720
}
67206721

6722+
#[test]
6723+
fn parse_pivot_table() {
6724+
let sql = concat!(
6725+
"SELECT * FROM monthly_sales AS a ",
6726+
"PIVOT(SUM(a.amount) FOR a.MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) AS p (c, d) ",
6727+
"ORDER BY EMPID"
6728+
);
6729+
6730+
assert_eq!(
6731+
verified_only_select(sql).from[0].relation,
6732+
Pivot {
6733+
name: ObjectName(vec![Ident::new("monthly_sales")]),
6734+
table_alias: Some(TableAlias {
6735+
name: Ident::new("a"),
6736+
columns: vec![]
6737+
}),
6738+
aggregate_function: Expr::Function(Function {
6739+
name: ObjectName(vec![Ident::new("SUM")]),
6740+
args: (vec![FunctionArg::Unnamed(FunctionArgExpr::Expr(
6741+
Expr::CompoundIdentifier(vec![Ident::new("a"), Ident::new("amount"),])
6742+
))]),
6743+
over: None,
6744+
distinct: false,
6745+
special: false,
6746+
}),
6747+
value_column: vec![Ident::new("a"), Ident::new("MONTH")],
6748+
pivot_values: vec![
6749+
Value::SingleQuotedString("JAN".to_string()),
6750+
Value::SingleQuotedString("FEB".to_string()),
6751+
Value::SingleQuotedString("MAR".to_string()),
6752+
Value::SingleQuotedString("APR".to_string()),
6753+
],
6754+
pivot_alias: Some(TableAlias {
6755+
name: Ident {
6756+
value: "p".to_string(),
6757+
quote_style: None
6758+
},
6759+
columns: vec![Ident::new("c"), Ident::new("d")],
6760+
}),
6761+
}
6762+
);
6763+
assert_eq!(verified_stmt(sql).to_string(), sql);
6764+
6765+
let sql_without_table_alias = concat!(
6766+
"SELECT * FROM monthly_sales ",
6767+
"PIVOT(SUM(a.amount) FOR a.MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) AS p (c, d) ",
6768+
"ORDER BY EMPID"
6769+
);
6770+
assert_matches!(
6771+
verified_only_select(sql_without_table_alias).from[0].relation,
6772+
Pivot {
6773+
table_alias: None, // parsing should succeed with empty alias
6774+
..
6775+
}
6776+
);
6777+
assert_eq!(
6778+
verified_stmt(sql_without_table_alias).to_string(),
6779+
sql_without_table_alias
6780+
);
6781+
}
6782+
67216783
/// Makes a predicate that looks like ((user_id = $id) OR user_id = $2...)
67226784
fn make_where_clause(num: usize) -> String {
67236785
use std::fmt::Write;

0 commit comments

Comments
 (0)