mirror of
https://github.com/apache/datafusion-sqlparser-rs.git
synced 2025-07-08 01:15:00 +00:00
add support for JSON_TABLE (#1062)
This commit is contained in:
parent
1933f194e7
commit
f46f147ffa
5 changed files with 238 additions and 5 deletions
|
@ -38,11 +38,12 @@ pub use self::ddl::{
|
|||
pub use self::operator::{BinaryOperator, UnaryOperator};
|
||||
pub use self::query::{
|
||||
Cte, Distinct, ExceptSelectItem, ExcludeSelectItem, Fetch, ForClause, ForJson, ForXml,
|
||||
GroupByExpr, IdentWithAlias, Join, JoinConstraint, JoinOperator, LateralView, LockClause,
|
||||
LockType, NamedWindowDefinition, NonBlock, Offset, OffsetRows, OrderByExpr, Query,
|
||||
RenameSelectItem, ReplaceSelectElement, ReplaceSelectItem, Select, SelectInto, SelectItem,
|
||||
SetExpr, SetOperator, SetQuantifier, Table, TableAlias, TableFactor, TableVersion,
|
||||
TableWithJoins, Top, Values, WildcardAdditionalOptions, With,
|
||||
GroupByExpr, IdentWithAlias, Join, JoinConstraint, JoinOperator, JsonTableColumn,
|
||||
JsonTableColumnErrorHandling, LateralView, LockClause, LockType, NamedWindowDefinition,
|
||||
NonBlock, Offset, OffsetRows, OrderByExpr, Query, RenameSelectItem, ReplaceSelectElement,
|
||||
ReplaceSelectItem, Select, SelectInto, SelectItem, SetExpr, SetOperator, SetQuantifier, Table,
|
||||
TableAlias, TableFactor, TableVersion, TableWithJoins, Top, Values, WildcardAdditionalOptions,
|
||||
With,
|
||||
};
|
||||
pub use self::value::{
|
||||
escape_quoted_string, DateTimeField, DollarQuotedString, TrimWhereField, Value,
|
||||
|
|
114
src/ast/query.rs
114
src/ast/query.rs
|
@ -726,6 +726,33 @@ pub enum TableFactor {
|
|||
with_offset: bool,
|
||||
with_offset_alias: Option<Ident>,
|
||||
},
|
||||
/// The `JSON_TABLE` table-valued function.
|
||||
/// Part of the SQL standard, but implemented only by MySQL, Oracle, and DB2.
|
||||
///
|
||||
/// <https://modern-sql.com/blog/2017-06/whats-new-in-sql-2016#json_table>
|
||||
/// <https://dev.mysql.com/doc/refman/8.0/en/json-table-functions.html#function_json-table>
|
||||
///
|
||||
/// ```sql
|
||||
/// SELECT * FROM JSON_TABLE(
|
||||
/// '[{"a": 1, "b": 2}, {"a": 3, "b": 4}]',
|
||||
/// '$[*]' COLUMNS(
|
||||
/// a INT PATH '$.a' DEFAULT '0' ON EMPTY,
|
||||
/// b INT PATH '$.b' NULL ON ERROR
|
||||
/// )
|
||||
/// ) AS jt;
|
||||
/// ````
|
||||
JsonTable {
|
||||
/// 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: 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<JsonTableColumn>,
|
||||
/// 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.
|
||||
|
@ -848,6 +875,22 @@ impl fmt::Display for TableFactor {
|
|||
}
|
||||
Ok(())
|
||||
}
|
||||
TableFactor::JsonTable {
|
||||
json_expr,
|
||||
json_path,
|
||||
columns,
|
||||
alias,
|
||||
} => {
|
||||
write!(
|
||||
f,
|
||||
"JSON_TABLE({json_expr}, {json_path} COLUMNS({columns}))",
|
||||
columns = display_comma_separated(columns)
|
||||
)?;
|
||||
if let Some(alias) = alias {
|
||||
write!(f, " AS {alias}")?;
|
||||
}
|
||||
Ok(())
|
||||
}
|
||||
TableFactor::NestedJoin {
|
||||
table_with_joins,
|
||||
alias,
|
||||
|
@ -1443,3 +1486,74 @@ impl fmt::Display for ForJson {
|
|||
}
|
||||
}
|
||||
}
|
||||
|
||||
/// A single column definition in MySQL's `JSON_TABLE` table valued function.
|
||||
/// ```sql
|
||||
/// SELECT *
|
||||
/// FROM JSON_TABLE(
|
||||
/// '["a", "b"]',
|
||||
/// '$[*]' COLUMNS (
|
||||
/// value VARCHAR(20) PATH '$'
|
||||
/// )
|
||||
/// ) AS jt;
|
||||
/// ```
|
||||
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
|
||||
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
|
||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||
pub struct JsonTableColumn {
|
||||
/// 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: Value,
|
||||
/// true if the column is a boolean set to true if the given path exists
|
||||
pub exists: bool,
|
||||
/// The empty handling clause of the column
|
||||
pub on_empty: Option<JsonTableColumnErrorHandling>,
|
||||
/// The error handling clause of the column
|
||||
pub on_error: Option<JsonTableColumnErrorHandling>,
|
||||
}
|
||||
|
||||
impl fmt::Display for JsonTableColumn {
|
||||
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
|
||||
write!(
|
||||
f,
|
||||
"{} {}{} PATH {}",
|
||||
self.name,
|
||||
self.r#type,
|
||||
if self.exists { " EXISTS" } else { "" },
|
||||
self.path
|
||||
)?;
|
||||
if let Some(on_empty) = &self.on_empty {
|
||||
write!(f, " {} ON EMPTY", on_empty)?;
|
||||
}
|
||||
if let Some(on_error) = &self.on_error {
|
||||
write!(f, " {} ON ERROR", on_error)?;
|
||||
}
|
||||
Ok(())
|
||||
}
|
||||
}
|
||||
|
||||
/// Stores the error handling clause of a `JSON_TABLE` table valued function:
|
||||
/// {NULL | DEFAULT json_string | ERROR} ON {ERROR | EMPTY }
|
||||
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
|
||||
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
|
||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||
pub enum JsonTableColumnErrorHandling {
|
||||
Null,
|
||||
Default(Value),
|
||||
Error,
|
||||
}
|
||||
|
||||
impl fmt::Display for JsonTableColumnErrorHandling {
|
||||
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
|
||||
match self {
|
||||
JsonTableColumnErrorHandling::Null => write!(f, "NULL"),
|
||||
JsonTableColumnErrorHandling::Default(json_string) => {
|
||||
write!(f, "DEFAULT {}", json_string)
|
||||
}
|
||||
JsonTableColumnErrorHandling::Error => write!(f, "ERROR"),
|
||||
}
|
||||
}
|
||||
}
|
||||
|
|
|
@ -237,6 +237,7 @@ define_keywords!(
|
|||
ELEMENT,
|
||||
ELEMENTS,
|
||||
ELSE,
|
||||
EMPTY,
|
||||
ENCODING,
|
||||
ENCRYPTION,
|
||||
END,
|
||||
|
@ -353,6 +354,7 @@ define_keywords!(
|
|||
JOIN,
|
||||
JSON,
|
||||
JSONFILE,
|
||||
JSON_TABLE,
|
||||
JULIAN,
|
||||
KEY,
|
||||
KILL,
|
||||
|
|
|
@ -6913,6 +6913,7 @@ impl<'a> Parser<'a> {
|
|||
| TableFactor::Table { alias, .. }
|
||||
| TableFactor::Function { alias, .. }
|
||||
| TableFactor::UNNEST { alias, .. }
|
||||
| TableFactor::JsonTable { alias, .. }
|
||||
| TableFactor::TableFunction { alias, .. }
|
||||
| TableFactor::Pivot { alias, .. }
|
||||
| TableFactor::Unpivot { alias, .. }
|
||||
|
@ -6971,6 +6972,23 @@ impl<'a> Parser<'a> {
|
|||
with_offset,
|
||||
with_offset_alias,
|
||||
})
|
||||
} else if self.parse_keyword(Keyword::JSON_TABLE) {
|
||||
self.expect_token(&Token::LParen)?;
|
||||
let json_expr = self.parse_expr()?;
|
||||
self.expect_token(&Token::Comma)?;
|
||||
let json_path = self.parse_value()?;
|
||||
self.expect_keyword(Keyword::COLUMNS)?;
|
||||
self.expect_token(&Token::LParen)?;
|
||||
let columns = self.parse_comma_separated(Parser::parse_json_table_column_def)?;
|
||||
self.expect_token(&Token::RParen)?;
|
||||
self.expect_token(&Token::RParen)?;
|
||||
let alias = self.parse_optional_table_alias(keywords::RESERVED_FOR_TABLE_ALIAS)?;
|
||||
Ok(TableFactor::JsonTable {
|
||||
json_expr,
|
||||
json_path,
|
||||
columns,
|
||||
alias,
|
||||
})
|
||||
} else {
|
||||
let name = self.parse_object_name()?;
|
||||
|
||||
|
@ -7041,6 +7059,50 @@ impl<'a> Parser<'a> {
|
|||
}
|
||||
}
|
||||
|
||||
/// Parses MySQL's JSON_TABLE column definition.
|
||||
/// For example: `id INT EXISTS PATH '$' DEFAULT '0' ON EMPTY ERROR ON ERROR`
|
||||
pub fn parse_json_table_column_def(&mut self) -> Result<JsonTableColumn, ParserError> {
|
||||
let name = self.parse_identifier()?;
|
||||
let r#type = self.parse_data_type()?;
|
||||
let exists = self.parse_keyword(Keyword::EXISTS);
|
||||
self.expect_keyword(Keyword::PATH)?;
|
||||
let path = self.parse_value()?;
|
||||
let mut on_empty = None;
|
||||
let mut on_error = None;
|
||||
while let Some(error_handling) = self.parse_json_table_column_error_handling()? {
|
||||
if self.parse_keyword(Keyword::EMPTY) {
|
||||
on_empty = Some(error_handling);
|
||||
} else {
|
||||
self.expect_keyword(Keyword::ERROR)?;
|
||||
on_error = Some(error_handling);
|
||||
}
|
||||
}
|
||||
Ok(JsonTableColumn {
|
||||
name,
|
||||
r#type,
|
||||
path,
|
||||
exists,
|
||||
on_empty,
|
||||
on_error,
|
||||
})
|
||||
}
|
||||
|
||||
fn parse_json_table_column_error_handling(
|
||||
&mut self,
|
||||
) -> Result<Option<JsonTableColumnErrorHandling>, ParserError> {
|
||||
let res = if self.parse_keyword(Keyword::NULL) {
|
||||
JsonTableColumnErrorHandling::Null
|
||||
} else if self.parse_keyword(Keyword::ERROR) {
|
||||
JsonTableColumnErrorHandling::Error
|
||||
} else if self.parse_keyword(Keyword::DEFAULT) {
|
||||
JsonTableColumnErrorHandling::Default(self.parse_value()?)
|
||||
} else {
|
||||
return Ok(None);
|
||||
};
|
||||
self.expect_keyword(Keyword::ON)?;
|
||||
Ok(Some(res))
|
||||
}
|
||||
|
||||
pub fn parse_derived_table_factor(
|
||||
&mut self,
|
||||
lateral: IsLateral,
|
||||
|
|
|
@ -1870,3 +1870,57 @@ fn parse_convert_using() {
|
|||
// with a type + a charset
|
||||
mysql().verified_only_select("SELECT CONVERT('test', CHAR CHARACTER SET utf8mb4)");
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_json_table() {
|
||||
mysql().verified_only_select("SELECT * FROM JSON_TABLE('[[1, 2], [3, 4]]', '$[*]' COLUMNS(a INT PATH '$[0]', b INT PATH '$[1]')) AS t");
|
||||
mysql().verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE('["x", "y"]', '$[*]' COLUMNS(a VARCHAR(20) PATH '$')) AS t"#,
|
||||
);
|
||||
// with a bound parameter
|
||||
mysql().verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE(?, '$[*]' COLUMNS(a VARCHAR(20) PATH '$')) AS t"#,
|
||||
);
|
||||
// quote escaping
|
||||
mysql().verified_only_select(r#"SELECT * FROM JSON_TABLE('{"''": [1,2,3]}', '$."''"[*]' COLUMNS(a VARCHAR(20) PATH '$')) AS t"#);
|
||||
// double quotes
|
||||
mysql().verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE("[]", "$[*]" COLUMNS(a VARCHAR(20) PATH "$")) AS t"#,
|
||||
);
|
||||
// exists
|
||||
mysql().verified_only_select(r#"SELECT * FROM JSON_TABLE('[{}, {"x":1}]', '$[*]' COLUMNS(x INT EXISTS PATH '$.x')) AS t"#);
|
||||
// error handling
|
||||
mysql().verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE('[1,2]', '$[*]' COLUMNS(x INT PATH '$' ERROR ON ERROR)) AS t"#,
|
||||
);
|
||||
mysql().verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE('[1,2]', '$[*]' COLUMNS(x INT PATH '$' ERROR ON EMPTY)) AS t"#,
|
||||
);
|
||||
mysql().verified_only_select(r#"SELECT * FROM JSON_TABLE('[1,2]', '$[*]' COLUMNS(x INT PATH '$' ERROR ON EMPTY DEFAULT '0' ON ERROR)) AS t"#);
|
||||
assert_eq!(
|
||||
mysql()
|
||||
.verified_only_select(
|
||||
r#"SELECT * FROM JSON_TABLE('[1,2]', '$[*]' COLUMNS(x INT PATH '$' DEFAULT '0' ON EMPTY NULL ON ERROR)) AS t"#
|
||||
)
|
||||
.from[0]
|
||||
.relation,
|
||||
TableFactor::JsonTable {
|
||||
json_expr: Expr::Value(Value::SingleQuotedString("[1,2]".to_string())),
|
||||
json_path: Value::SingleQuotedString("$[*]".to_string()),
|
||||
columns: vec![
|
||||
JsonTableColumn {
|
||||
name: Ident::new("x"),
|
||||
r#type: DataType::Int(None),
|
||||
path: Value::SingleQuotedString("$".to_string()),
|
||||
exists: false,
|
||||
on_empty: Some(JsonTableColumnErrorHandling::Default(Value::SingleQuotedString("0".to_string()))),
|
||||
on_error: Some(JsonTableColumnErrorHandling::Null),
|
||||
},
|
||||
],
|
||||
alias: Some(TableAlias {
|
||||
name: Ident::new("t"),
|
||||
columns: vec![],
|
||||
}),
|
||||
}
|
||||
);
|
||||
}
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue