Add support for MSSQL's OPENJSON WITH clause (#1498)

This commit is contained in:
gaoqiangz 2024-11-13 14:41:13 +08:00 committed by GitHub
parent e857787309
commit 90824486df
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
5 changed files with 476 additions and 6 deletions

View file

@ -56,12 +56,12 @@ pub use self::query::{
InterpolateExpr, Join, JoinConstraint, JoinOperator, JsonTableColumn,
JsonTableColumnErrorHandling, JsonTableNamedColumn, JsonTableNestedColumn, LateralView,
LockClause, LockType, MatchRecognizePattern, MatchRecognizeSymbol, Measure,
NamedWindowDefinition, NamedWindowExpr, NonBlock, Offset, OffsetRows, OrderBy, OrderByExpr,
PivotValueSource, ProjectionSelect, Query, RenameSelectItem, RepetitionQuantifier,
ReplaceSelectElement, ReplaceSelectItem, RowsPerMatch, Select, SelectInto, SelectItem, SetExpr,
SetOperator, SetQuantifier, Setting, SymbolDefinition, Table, TableAlias, TableFactor,
TableFunctionArgs, TableVersion, TableWithJoins, Top, TopQuantity, ValueTableMode, Values,
WildcardAdditionalOptions, With, WithFill,
NamedWindowDefinition, NamedWindowExpr, NonBlock, Offset, OffsetRows, OpenJsonTableColumn,
OrderBy, OrderByExpr, PivotValueSource, ProjectionSelect, Query, RenameSelectItem,
RepetitionQuantifier, ReplaceSelectElement, ReplaceSelectItem, RowsPerMatch, Select,
SelectInto, SelectItem, SetExpr, SetOperator, SetQuantifier, Setting, SymbolDefinition, Table,
TableAlias, TableFactor, TableFunctionArgs, TableVersion, TableWithJoins, Top, TopQuantity,
ValueTableMode, Values, WildcardAdditionalOptions, With, WithFill,
};
pub use self::trigger::{

View file

@ -1036,6 +1036,27 @@ pub enum TableFactor {
/// The alias for the table.
alias: Option<TableAlias>,
},
/// The MSSQL's `OPENJSON` table-valued function.
///
/// ```sql
/// OPENJSON( jsonExpression [ , path ] ) [ <with_clause> ]
///
/// <with_clause> ::= WITH ( { colName type [ column_path ] [ AS JSON ] } [ ,...n ] )
/// ````
///
/// Reference: <https://learn.microsoft.com/en-us/sql/t-sql/functions/openjson-transact-sql?view=sql-server-ver16#syntax>
OpenJsonTable {
/// The JSON expression to be evaluated. It must evaluate to a json string
json_expr: Expr,
/// The path to the array or object to be iterated over.
/// It must evaluate to a json array or object.
json_path: Option<Value>,
/// The columns to be extracted from each element of the array or object.
/// Each column must have a name and a type.
columns: Vec<OpenJsonTableColumn>,
/// The alias for the table.
alias: Option<TableAlias>,
},
/// Represents a parenthesized table factor. The SQL spec only allows a
/// join expression (`(foo <JOIN> bar [ <JOIN> baz ... ])`) to be nested,
/// possibly several times.
@ -1461,6 +1482,25 @@ impl fmt::Display for TableFactor {
}
Ok(())
}
TableFactor::OpenJsonTable {
json_expr,
json_path,
columns,
alias,
} => {
write!(f, "OPENJSON({json_expr}")?;
if let Some(json_path) = json_path {
write!(f, ", {json_path}")?;
}
write!(f, ")")?;
if !columns.is_empty() {
write!(f, " WITH ({})", display_comma_separated(columns))?;
}
if let Some(alias) = alias {
write!(f, " AS {alias}")?;
}
Ok(())
}
TableFactor::NestedJoin {
table_with_joins,
alias,
@ -2421,6 +2461,40 @@ impl fmt::Display for JsonTableColumnErrorHandling {
}
}
/// A single column definition in MSSQL's `OPENJSON WITH` clause.
///
/// ```sql
/// colName type [ column_path ] [ AS JSON ]
/// ```
///
/// Reference: <https://learn.microsoft.com/en-us/sql/t-sql/functions/openjson-transact-sql?view=sql-server-ver16#syntax>
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
pub struct OpenJsonTableColumn {
/// The name of the column to be extracted.
pub name: Ident,
/// The type of the column to be extracted.
pub r#type: DataType,
/// The path to the column to be extracted. Must be a literal string.
pub path: Option<String>,
/// The `AS JSON` option.
pub as_json: bool,
}
impl fmt::Display for OpenJsonTableColumn {
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
write!(f, "{} {}", self.name, self.r#type)?;
if let Some(path) = &self.path {
write!(f, " '{}'", value::escape_single_quote_string(path))?;
}
if self.as_json {
write!(f, " AS JSON")?;
}
Ok(())
}
}
/// BigQuery supports ValueTables which have 2 modes:
/// `SELECT AS STRUCT`
/// `SELECT AS VALUE`

View file

@ -537,6 +537,7 @@ define_keywords!(
ONE,
ONLY,
OPEN,
OPENJSON,
OPERATOR,
OPTIMIZE,
OPTIMIZER_COSTS,

View file

@ -10049,6 +10049,7 @@ impl<'a> Parser<'a> {
| TableFactor::Function { alias, .. }
| TableFactor::UNNEST { alias, .. }
| TableFactor::JsonTable { alias, .. }
| TableFactor::OpenJsonTable { alias, .. }
| TableFactor::TableFunction { alias, .. }
| TableFactor::Pivot { alias, .. }
| TableFactor::Unpivot { alias, .. }
@ -10162,6 +10163,9 @@ impl<'a> Parser<'a> {
columns,
alias,
})
} else if self.parse_keyword_with_tokens(Keyword::OPENJSON, &[Token::LParen]) {
self.prev_token();
self.parse_open_json_table_factor()
} else {
let name = self.parse_object_name(true)?;
@ -10227,6 +10231,34 @@ impl<'a> Parser<'a> {
}
}
/// Parses `OPENJSON( jsonExpression [ , path ] ) [ <with_clause> ]` clause,
/// assuming the `OPENJSON` keyword was already consumed.
fn parse_open_json_table_factor(&mut self) -> Result<TableFactor, ParserError> {
self.expect_token(&Token::LParen)?;
let json_expr = self.parse_expr()?;
let json_path = if self.consume_token(&Token::Comma) {
Some(self.parse_value()?)
} else {
None
};
self.expect_token(&Token::RParen)?;
let columns = if self.parse_keyword(Keyword::WITH) {
self.expect_token(&Token::LParen)?;
let columns = self.parse_comma_separated(Parser::parse_openjson_table_column_def)?;
self.expect_token(&Token::RParen)?;
columns
} else {
Vec::new()
};
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
Ok(TableFactor::OpenJsonTable {
json_expr,
json_path,
columns,
alias,
})
}
fn parse_match_recognize(&mut self, table: TableFactor) -> Result<TableFactor, ParserError> {
self.expect_token(&Token::LParen)?;
@ -10513,6 +10545,34 @@ impl<'a> Parser<'a> {
}))
}
/// Parses MSSQL's `OPENJSON WITH` column definition.
///
/// ```sql
/// colName type [ column_path ] [ AS JSON ]
/// ```
///
/// Reference: <https://learn.microsoft.com/en-us/sql/t-sql/functions/openjson-transact-sql?view=sql-server-ver16#syntax>
pub fn parse_openjson_table_column_def(&mut self) -> Result<OpenJsonTableColumn, ParserError> {
let name = self.parse_identifier(false)?;
let r#type = self.parse_data_type()?;
let path = if let Token::SingleQuotedString(path) = self.peek_token().token {
self.next_token();
Some(path)
} else {
None
};
let as_json = self.parse_keyword(Keyword::AS);
if as_json {
self.expect_keyword(Keyword::JSON)?;
}
Ok(OpenJsonTableColumn {
name,
r#type,
path,
as_json,
})
}
fn parse_json_table_column_error_handling(
&mut self,
) -> Result<Option<JsonTableColumnErrorHandling>, ParserError> {

View file

@ -193,6 +193,341 @@ fn parse_mssql_apply_join() {
);
}
#[test]
fn parse_mssql_openjson() {
let select = ms().verified_only_select(
"SELECT B.kind, B.id_list \
FROM t_test_table AS A \
CROSS APPLY OPENJSON(A.param, '$.config') WITH (kind VARCHAR(20) '$.kind', [id_list] NVARCHAR(MAX) '$.id_list' AS JSON) AS B",
);
assert_eq!(
vec![TableWithJoins {
relation: TableFactor::Table {
name: ObjectName(vec![Ident {
value: "t_test_table".into(),
quote_style: None,
},]),
alias: Some(TableAlias {
name: Ident {
value: "A".into(),
quote_style: None
},
columns: vec![]
}),
args: None,
with_hints: vec![],
version: None,
with_ordinality: false,
partitions: vec![]
},
joins: vec![Join {
relation: TableFactor::OpenJsonTable {
json_expr: Expr::CompoundIdentifier(vec![
Ident {
value: "A".into(),
quote_style: None,
},
Ident {
value: "param".into(),
quote_style: None,
}
]),
json_path: Some(Value::SingleQuotedString("$.config".into())),
columns: vec![
OpenJsonTableColumn {
name: Ident {
value: "kind".into(),
quote_style: None,
},
r#type: DataType::Varchar(Some(CharacterLength::IntegerLength {
length: 20,
unit: None
})),
path: Some("$.kind".into()),
as_json: false
},
OpenJsonTableColumn {
name: Ident {
value: "id_list".into(),
quote_style: Some('['),
},
r#type: DataType::Nvarchar(Some(CharacterLength::Max)),
path: Some("$.id_list".into()),
as_json: true
}
],
alias: Some(TableAlias {
name: Ident {
value: "B".into(),
quote_style: None
},
columns: vec![]
})
},
global: false,
join_operator: JoinOperator::CrossApply
}]
}],
select.from
);
let select = ms().verified_only_select(
"SELECT B.kind, B.id_list \
FROM t_test_table AS A \
CROSS APPLY OPENJSON(A.param) WITH (kind VARCHAR(20) '$.kind', [id_list] NVARCHAR(MAX) '$.id_list' AS JSON) AS B",
);
assert_eq!(
vec![TableWithJoins {
relation: TableFactor::Table {
name: ObjectName(vec![Ident {
value: "t_test_table".into(),
quote_style: None,
},]),
alias: Some(TableAlias {
name: Ident {
value: "A".into(),
quote_style: None
},
columns: vec![]
}),
args: None,
with_hints: vec![],
version: None,
with_ordinality: false,
partitions: vec![]
},
joins: vec![Join {
relation: TableFactor::OpenJsonTable {
json_expr: Expr::CompoundIdentifier(vec![
Ident {
value: "A".into(),
quote_style: None,
},
Ident {
value: "param".into(),
quote_style: None,
}
]),
json_path: None,
columns: vec![
OpenJsonTableColumn {
name: Ident {
value: "kind".into(),
quote_style: None,
},
r#type: DataType::Varchar(Some(CharacterLength::IntegerLength {
length: 20,
unit: None
})),
path: Some("$.kind".into()),
as_json: false
},
OpenJsonTableColumn {
name: Ident {
value: "id_list".into(),
quote_style: Some('['),
},
r#type: DataType::Nvarchar(Some(CharacterLength::Max)),
path: Some("$.id_list".into()),
as_json: true
}
],
alias: Some(TableAlias {
name: Ident {
value: "B".into(),
quote_style: None
},
columns: vec![]
})
},
global: false,
join_operator: JoinOperator::CrossApply
}]
}],
select.from
);
let select = ms().verified_only_select(
"SELECT B.kind, B.id_list \
FROM t_test_table AS A \
CROSS APPLY OPENJSON(A.param) WITH (kind VARCHAR(20), [id_list] NVARCHAR(MAX)) AS B",
);
assert_eq!(
vec![TableWithJoins {
relation: TableFactor::Table {
name: ObjectName(vec![Ident {
value: "t_test_table".into(),
quote_style: None,
},]),
alias: Some(TableAlias {
name: Ident {
value: "A".into(),
quote_style: None
},
columns: vec![]
}),
args: None,
with_hints: vec![],
version: None,
with_ordinality: false,
partitions: vec![]
},
joins: vec![Join {
relation: TableFactor::OpenJsonTable {
json_expr: Expr::CompoundIdentifier(vec![
Ident {
value: "A".into(),
quote_style: None,
},
Ident {
value: "param".into(),
quote_style: None,
}
]),
json_path: None,
columns: vec![
OpenJsonTableColumn {
name: Ident {
value: "kind".into(),
quote_style: None,
},
r#type: DataType::Varchar(Some(CharacterLength::IntegerLength {
length: 20,
unit: None
})),
path: None,
as_json: false
},
OpenJsonTableColumn {
name: Ident {
value: "id_list".into(),
quote_style: Some('['),
},
r#type: DataType::Nvarchar(Some(CharacterLength::Max)),
path: None,
as_json: false
}
],
alias: Some(TableAlias {
name: Ident {
value: "B".into(),
quote_style: None
},
columns: vec![]
})
},
global: false,
join_operator: JoinOperator::CrossApply
}]
}],
select.from
);
let select = ms_and_generic().verified_only_select(
"SELECT B.kind, B.id_list \
FROM t_test_table AS A \
CROSS APPLY OPENJSON(A.param, '$.config') AS B",
);
assert_eq!(
vec![TableWithJoins {
relation: TableFactor::Table {
name: ObjectName(vec![Ident {
value: "t_test_table".into(),
quote_style: None,
},]),
alias: Some(TableAlias {
name: Ident {
value: "A".into(),
quote_style: None
},
columns: vec![]
}),
args: None,
with_hints: vec![],
version: None,
with_ordinality: false,
partitions: vec![]
},
joins: vec![Join {
relation: TableFactor::OpenJsonTable {
json_expr: Expr::CompoundIdentifier(vec![
Ident {
value: "A".into(),
quote_style: None,
},
Ident {
value: "param".into(),
quote_style: None,
}
]),
json_path: Some(Value::SingleQuotedString("$.config".into())),
columns: vec![],
alias: Some(TableAlias {
name: Ident {
value: "B".into(),
quote_style: None
},
columns: vec![]
})
},
global: false,
join_operator: JoinOperator::CrossApply
}]
}],
select.from
);
let select = ms_and_generic().verified_only_select(
"SELECT B.kind, B.id_list \
FROM t_test_table AS A \
CROSS APPLY OPENJSON(A.param) AS B",
);
assert_eq!(
vec![TableWithJoins {
relation: TableFactor::Table {
name: ObjectName(vec![Ident {
value: "t_test_table".into(),
quote_style: None,
},]),
alias: Some(TableAlias {
name: Ident {
value: "A".into(),
quote_style: None
},
columns: vec![]
}),
args: None,
with_hints: vec![],
version: None,
with_ordinality: false,
partitions: vec![]
},
joins: vec![Join {
relation: TableFactor::OpenJsonTable {
json_expr: Expr::CompoundIdentifier(vec![
Ident {
value: "A".into(),
quote_style: None,
},
Ident {
value: "param".into(),
quote_style: None,
}
]),
json_path: None,
columns: vec![],
alias: Some(TableAlias {
name: Ident {
value: "B".into(),
quote_style: None
},
columns: vec![]
})
},
global: false,
join_operator: JoinOperator::CrossApply
}]
}],
select.from
);
}
#[test]
fn parse_mssql_top_paren() {
let sql = "SELECT TOP (5) * FROM foo";