mirror of
https://github.com/apache/datafusion-sqlparser-rs.git
synced 2025-09-26 15:39:12 +00:00
Extend pivot operator support (#1238)
This commit is contained in:
parent
4bfa399919
commit
8626051513
5 changed files with 140 additions and 52 deletions
|
@ -41,14 +41,14 @@ pub use self::dml::{Delete, Insert};
|
||||||
pub use self::operator::{BinaryOperator, UnaryOperator};
|
pub use self::operator::{BinaryOperator, UnaryOperator};
|
||||||
pub use self::query::{
|
pub use self::query::{
|
||||||
AfterMatchSkip, ConnectBy, Cte, CteAsMaterialized, Distinct, EmptyMatchesMode,
|
AfterMatchSkip, ConnectBy, Cte, CteAsMaterialized, Distinct, EmptyMatchesMode,
|
||||||
ExceptSelectItem, ExcludeSelectItem, Fetch, ForClause, ForJson, ForXml, GroupByExpr,
|
ExceptSelectItem, ExcludeSelectItem, ExprWithAlias, Fetch, ForClause, ForJson, ForXml,
|
||||||
IdentWithAlias, IlikeSelectItem, Join, JoinConstraint, JoinOperator, JsonTableColumn,
|
GroupByExpr, IdentWithAlias, IlikeSelectItem, Join, JoinConstraint, JoinOperator,
|
||||||
JsonTableColumnErrorHandling, LateralView, LockClause, LockType, MatchRecognizePattern,
|
JsonTableColumn, JsonTableColumnErrorHandling, LateralView, LockClause, LockType,
|
||||||
MatchRecognizeSymbol, Measure, NamedWindowDefinition, NamedWindowExpr, NonBlock, Offset,
|
MatchRecognizePattern, MatchRecognizeSymbol, Measure, NamedWindowDefinition, NamedWindowExpr,
|
||||||
OffsetRows, OrderByExpr, Query, RenameSelectItem, RepetitionQuantifier, ReplaceSelectElement,
|
NonBlock, Offset, OffsetRows, OrderByExpr, Query, RenameSelectItem, RepetitionQuantifier,
|
||||||
ReplaceSelectItem, RowsPerMatch, Select, SelectInto, SelectItem, SetExpr, SetOperator,
|
ReplaceSelectElement, ReplaceSelectItem, RowsPerMatch, Select, SelectInto, SelectItem, SetExpr,
|
||||||
SetQuantifier, SymbolDefinition, Table, TableAlias, TableFactor, TableVersion, TableWithJoins,
|
SetOperator, SetQuantifier, SymbolDefinition, Table, TableAlias, TableFactor, TableVersion,
|
||||||
Top, TopQuantity, ValueTableMode, Values, WildcardAdditionalOptions, With,
|
TableWithJoins, Top, TopQuantity, ValueTableMode, Values, WildcardAdditionalOptions, With,
|
||||||
};
|
};
|
||||||
pub use self::value::{
|
pub use self::value::{
|
||||||
escape_double_quote_string, escape_quoted_string, DateTimeField, DollarQuotedString,
|
escape_double_quote_string, escape_quoted_string, DateTimeField, DollarQuotedString,
|
||||||
|
|
|
@ -802,6 +802,31 @@ impl fmt::Display for ConnectBy {
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/// An expression optionally followed by an alias.
|
||||||
|
///
|
||||||
|
/// Example:
|
||||||
|
/// ```sql
|
||||||
|
/// 42 AS myint
|
||||||
|
/// ```
|
||||||
|
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
|
||||||
|
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||||
|
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
|
||||||
|
pub struct ExprWithAlias {
|
||||||
|
pub expr: Expr,
|
||||||
|
pub alias: Option<Ident>,
|
||||||
|
}
|
||||||
|
|
||||||
|
impl fmt::Display for ExprWithAlias {
|
||||||
|
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
|
||||||
|
let ExprWithAlias { expr, alias } = self;
|
||||||
|
write!(f, "{expr}")?;
|
||||||
|
if let Some(alias) = alias {
|
||||||
|
write!(f, " AS {alias}")?;
|
||||||
|
}
|
||||||
|
Ok(())
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
/// A table name or a parenthesized subquery with an optional alias
|
/// A table name or a parenthesized subquery with an optional alias
|
||||||
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
|
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
|
||||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||||
|
@ -900,12 +925,14 @@ pub enum TableFactor {
|
||||||
},
|
},
|
||||||
/// Represents PIVOT operation on a table.
|
/// Represents PIVOT operation on a table.
|
||||||
/// For example `FROM monthly_sales PIVOT(sum(amount) FOR MONTH IN ('JAN', 'FEB'))`
|
/// For example `FROM monthly_sales PIVOT(sum(amount) FOR MONTH IN ('JAN', 'FEB'))`
|
||||||
/// See <https://docs.snowflake.com/en/sql-reference/constructs/pivot>
|
///
|
||||||
|
/// [BigQuery](https://cloud.google.com/bigquery/docs/reference/standard-sql/query-syntax#pivot_operator)
|
||||||
|
/// [Snowflake](https://docs.snowflake.com/en/sql-reference/constructs/pivot)
|
||||||
Pivot {
|
Pivot {
|
||||||
table: Box<TableFactor>,
|
table: Box<TableFactor>,
|
||||||
aggregate_function: Expr, // Function expression
|
aggregate_functions: Vec<ExprWithAlias>, // Function expression
|
||||||
value_column: Vec<Ident>,
|
value_column: Vec<Ident>,
|
||||||
pivot_values: Vec<Value>,
|
pivot_values: Vec<ExprWithAlias>,
|
||||||
alias: Option<TableAlias>,
|
alias: Option<TableAlias>,
|
||||||
},
|
},
|
||||||
/// An UNPIVOT operation on a table.
|
/// An UNPIVOT operation on a table.
|
||||||
|
@ -1270,7 +1297,7 @@ impl fmt::Display for TableFactor {
|
||||||
}
|
}
|
||||||
TableFactor::Pivot {
|
TableFactor::Pivot {
|
||||||
table,
|
table,
|
||||||
aggregate_function,
|
aggregate_functions,
|
||||||
value_column,
|
value_column,
|
||||||
pivot_values,
|
pivot_values,
|
||||||
alias,
|
alias,
|
||||||
|
@ -1279,7 +1306,7 @@ impl fmt::Display for TableFactor {
|
||||||
f,
|
f,
|
||||||
"{} PIVOT({} FOR {} IN ({}))",
|
"{} PIVOT({} FOR {} IN ({}))",
|
||||||
table,
|
table,
|
||||||
aggregate_function,
|
display_comma_separated(aggregate_functions),
|
||||||
Expr::CompoundIdentifier(value_column.to_vec()),
|
Expr::CompoundIdentifier(value_column.to_vec()),
|
||||||
display_comma_separated(pivot_values)
|
display_comma_separated(pivot_values)
|
||||||
)?;
|
)?;
|
||||||
|
|
|
@ -850,6 +850,14 @@ mod tests {
|
||||||
"PRE: EXPR: a.amount",
|
"PRE: EXPR: a.amount",
|
||||||
"POST: EXPR: a.amount",
|
"POST: EXPR: a.amount",
|
||||||
"POST: EXPR: SUM(a.amount)",
|
"POST: EXPR: SUM(a.amount)",
|
||||||
|
"PRE: EXPR: 'JAN'",
|
||||||
|
"POST: EXPR: 'JAN'",
|
||||||
|
"PRE: EXPR: 'FEB'",
|
||||||
|
"POST: EXPR: 'FEB'",
|
||||||
|
"PRE: EXPR: 'MAR'",
|
||||||
|
"POST: EXPR: 'MAR'",
|
||||||
|
"PRE: EXPR: 'APR'",
|
||||||
|
"POST: EXPR: 'APR'",
|
||||||
"POST: TABLE FACTOR: monthly_sales PIVOT(SUM(a.amount) FOR a.MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) AS p (c, d)",
|
"POST: TABLE FACTOR: monthly_sales PIVOT(SUM(a.amount) FOR a.MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) AS p (c, d)",
|
||||||
"PRE: EXPR: EMPID",
|
"PRE: EXPR: EMPID",
|
||||||
"POST: EXPR: EMPID",
|
"POST: EXPR: EMPID",
|
||||||
|
|
|
@ -8775,27 +8775,49 @@ impl<'a> Parser<'a> {
|
||||||
})
|
})
|
||||||
}
|
}
|
||||||
|
|
||||||
|
fn parse_aliased_function_call(&mut self) -> Result<ExprWithAlias, ParserError> {
|
||||||
|
let function_name = match self.next_token().token {
|
||||||
|
Token::Word(w) => Ok(w.value),
|
||||||
|
_ => self.expected("a function identifier", self.peek_token()),
|
||||||
|
}?;
|
||||||
|
let expr = self.parse_function(ObjectName(vec![Ident::new(function_name)]))?;
|
||||||
|
let alias = if self.parse_keyword(Keyword::AS) {
|
||||||
|
Some(self.parse_identifier(false)?)
|
||||||
|
} else {
|
||||||
|
None
|
||||||
|
};
|
||||||
|
|
||||||
|
Ok(ExprWithAlias { expr, alias })
|
||||||
|
}
|
||||||
|
|
||||||
|
fn parse_expr_with_alias(&mut self) -> Result<ExprWithAlias, ParserError> {
|
||||||
|
let expr = self.parse_expr()?;
|
||||||
|
let alias = if self.parse_keyword(Keyword::AS) {
|
||||||
|
Some(self.parse_identifier(false)?)
|
||||||
|
} else {
|
||||||
|
None
|
||||||
|
};
|
||||||
|
|
||||||
|
Ok(ExprWithAlias { expr, alias })
|
||||||
|
}
|
||||||
|
|
||||||
pub fn parse_pivot_table_factor(
|
pub fn parse_pivot_table_factor(
|
||||||
&mut self,
|
&mut self,
|
||||||
table: TableFactor,
|
table: TableFactor,
|
||||||
) -> Result<TableFactor, ParserError> {
|
) -> Result<TableFactor, ParserError> {
|
||||||
self.expect_token(&Token::LParen)?;
|
self.expect_token(&Token::LParen)?;
|
||||||
let function_name = match self.next_token().token {
|
let aggregate_functions = self.parse_comma_separated(Self::parse_aliased_function_call)?;
|
||||||
Token::Word(w) => Ok(w.value),
|
|
||||||
_ => self.expected("an aggregate function name", self.peek_token()),
|
|
||||||
}?;
|
|
||||||
let function = self.parse_function(ObjectName(vec![Ident::new(function_name)]))?;
|
|
||||||
self.expect_keyword(Keyword::FOR)?;
|
self.expect_keyword(Keyword::FOR)?;
|
||||||
let value_column = self.parse_object_name(false)?.0;
|
let value_column = self.parse_object_name(false)?.0;
|
||||||
self.expect_keyword(Keyword::IN)?;
|
self.expect_keyword(Keyword::IN)?;
|
||||||
self.expect_token(&Token::LParen)?;
|
self.expect_token(&Token::LParen)?;
|
||||||
let pivot_values = self.parse_comma_separated(Parser::parse_value)?;
|
let pivot_values = self.parse_comma_separated(Self::parse_expr_with_alias)?;
|
||||||
self.expect_token(&Token::RParen)?;
|
self.expect_token(&Token::RParen)?;
|
||||||
self.expect_token(&Token::RParen)?;
|
self.expect_token(&Token::RParen)?;
|
||||||
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
|
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
|
||||||
Ok(TableFactor::Pivot {
|
Ok(TableFactor::Pivot {
|
||||||
table: Box::new(table),
|
table: Box::new(table),
|
||||||
aggregate_function: function,
|
aggregate_functions,
|
||||||
value_column,
|
value_column,
|
||||||
pivot_values,
|
pivot_values,
|
||||||
alias,
|
alias,
|
||||||
|
|
|
@ -8453,11 +8453,32 @@ fn parse_escaped_string_without_unescape() {
|
||||||
#[test]
|
#[test]
|
||||||
fn parse_pivot_table() {
|
fn parse_pivot_table() {
|
||||||
let sql = concat!(
|
let sql = concat!(
|
||||||
"SELECT * FROM monthly_sales AS a ",
|
"SELECT * FROM monthly_sales AS a PIVOT(",
|
||||||
"PIVOT(SUM(a.amount) FOR a.MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) AS p (c, d) ",
|
"SUM(a.amount), ",
|
||||||
|
"SUM(b.amount) AS t, ",
|
||||||
|
"SUM(c.amount) AS u ",
|
||||||
|
"FOR a.MONTH IN (1 AS x, 'two', three AS y)) AS p (c, d) ",
|
||||||
"ORDER BY EMPID"
|
"ORDER BY EMPID"
|
||||||
);
|
);
|
||||||
|
|
||||||
|
fn expected_function(table: &'static str, alias: Option<&'static str>) -> ExprWithAlias {
|
||||||
|
ExprWithAlias {
|
||||||
|
expr: Expr::Function(Function {
|
||||||
|
name: ObjectName(vec![Ident::new("SUM")]),
|
||||||
|
args: (vec![FunctionArg::Unnamed(FunctionArgExpr::Expr(
|
||||||
|
Expr::CompoundIdentifier(vec![Ident::new(table), Ident::new("amount")]),
|
||||||
|
))]),
|
||||||
|
null_treatment: None,
|
||||||
|
filter: None,
|
||||||
|
over: None,
|
||||||
|
distinct: false,
|
||||||
|
special: false,
|
||||||
|
order_by: vec![],
|
||||||
|
}),
|
||||||
|
alias: alias.map(Ident::new),
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
assert_eq!(
|
assert_eq!(
|
||||||
verified_only_select(sql).from[0].relation,
|
verified_only_select(sql).from[0].relation,
|
||||||
Pivot {
|
Pivot {
|
||||||
|
@ -8472,24 +8493,25 @@ fn parse_pivot_table() {
|
||||||
version: None,
|
version: None,
|
||||||
partitions: vec![],
|
partitions: vec![],
|
||||||
}),
|
}),
|
||||||
aggregate_function: Expr::Function(Function {
|
aggregate_functions: vec![
|
||||||
name: ObjectName(vec![Ident::new("SUM")]),
|
expected_function("a", None),
|
||||||
args: (vec![FunctionArg::Unnamed(FunctionArgExpr::Expr(
|
expected_function("b", Some("t")),
|
||||||
Expr::CompoundIdentifier(vec![Ident::new("a"), Ident::new("amount"),])
|
expected_function("c", Some("u")),
|
||||||
))]),
|
],
|
||||||
null_treatment: None,
|
|
||||||
filter: None,
|
|
||||||
over: None,
|
|
||||||
distinct: false,
|
|
||||||
special: false,
|
|
||||||
order_by: vec![],
|
|
||||||
}),
|
|
||||||
value_column: vec![Ident::new("a"), Ident::new("MONTH")],
|
value_column: vec![Ident::new("a"), Ident::new("MONTH")],
|
||||||
pivot_values: vec![
|
pivot_values: vec![
|
||||||
Value::SingleQuotedString("JAN".to_string()),
|
ExprWithAlias {
|
||||||
Value::SingleQuotedString("FEB".to_string()),
|
expr: Expr::Value(number("1")),
|
||||||
Value::SingleQuotedString("MAR".to_string()),
|
alias: Some(Ident::new("x"))
|
||||||
Value::SingleQuotedString("APR".to_string()),
|
},
|
||||||
|
ExprWithAlias {
|
||||||
|
expr: Expr::Value(Value::SingleQuotedString("two".to_string())),
|
||||||
|
alias: None
|
||||||
|
},
|
||||||
|
ExprWithAlias {
|
||||||
|
expr: Expr::Identifier(Ident::new("three")),
|
||||||
|
alias: Some(Ident::new("y"))
|
||||||
|
},
|
||||||
],
|
],
|
||||||
alias: Some(TableAlias {
|
alias: Some(TableAlias {
|
||||||
name: Ident {
|
name: Ident {
|
||||||
|
@ -8623,22 +8645,31 @@ fn parse_pivot_unpivot_table() {
|
||||||
columns: vec![]
|
columns: vec![]
|
||||||
}),
|
}),
|
||||||
}),
|
}),
|
||||||
aggregate_function: Expr::Function(Function {
|
aggregate_functions: vec![ExprWithAlias {
|
||||||
name: ObjectName(vec![Ident::new("sum")]),
|
expr: Expr::Function(Function {
|
||||||
args: (vec![FunctionArg::Unnamed(FunctionArgExpr::Expr(
|
name: ObjectName(vec![Ident::new("sum")]),
|
||||||
Expr::Identifier(Ident::new("population"))
|
args: (vec![FunctionArg::Unnamed(FunctionArgExpr::Expr(
|
||||||
))]),
|
Expr::Identifier(Ident::new("population"))
|
||||||
null_treatment: None,
|
))]),
|
||||||
filter: None,
|
null_treatment: None,
|
||||||
over: None,
|
filter: None,
|
||||||
distinct: false,
|
over: None,
|
||||||
special: false,
|
distinct: false,
|
||||||
order_by: vec![],
|
special: false,
|
||||||
}),
|
order_by: vec![],
|
||||||
|
}),
|
||||||
|
alias: None
|
||||||
|
}],
|
||||||
value_column: vec![Ident::new("year")],
|
value_column: vec![Ident::new("year")],
|
||||||
pivot_values: vec![
|
pivot_values: vec![
|
||||||
Value::SingleQuotedString("population_2000".to_string()),
|
ExprWithAlias {
|
||||||
Value::SingleQuotedString("population_2010".to_string())
|
expr: Expr::Value(Value::SingleQuotedString("population_2000".to_string())),
|
||||||
|
alias: None
|
||||||
|
},
|
||||||
|
ExprWithAlias {
|
||||||
|
expr: Expr::Value(Value::SingleQuotedString("population_2010".to_string())),
|
||||||
|
alias: None
|
||||||
|
},
|
||||||
],
|
],
|
||||||
alias: Some(TableAlias {
|
alias: Some(TableAlias {
|
||||||
name: Ident::new("p"),
|
name: Ident::new("p"),
|
||||||
|
|
Loading…
Add table
Add a link
Reference in a new issue