mirror of
https://github.com/apache/datafusion-sqlparser-rs.git
synced 2025-07-07 17:04:59 +00:00
Implement some MySQL specific syntax and extend the UPDATE statement (#375)
* * implement the ON DUPLICATE KEY syntax for MySQL in an INSERT statement * * add MySQL to the cli example * remove the dialect check for the ON DUPLICATE KEY insert to support custom dialects and unwrap some missing results * * use the Assignment DataType for the ON DUPLICATE KEY UPDATE * * add support for table aliases in an UPDATE statement * add support for JOINS in an UPDATE statement (for MySQL) * * implement the MySQL ALTER TABLE CHANGE COLUMN syntax * * fix the formatting of the else * rename the parse_identifiers_strict to parse_identifiers_non_keywords * Parse SUBSTRING calls that are separated with a comma instead of keywords * Fix the linting errors Co-authored-by: Piotr <piotr.morawski@nc-vision.com> Co-authored-by: Piotr Morawski <contact@peter-morawski.de>
This commit is contained in:
parent
40d67aab87
commit
82eaae1522
7 changed files with 489 additions and 18 deletions
|
@ -40,6 +40,7 @@ $ cargo run --feature json_example --example cli FILENAME.sql [--dialectname]
|
|||
"--ansi" => Box::new(AnsiDialect {}),
|
||||
"--postgres" => Box::new(PostgreSqlDialect {}),
|
||||
"--ms" => Box::new(MsSqlDialect {}),
|
||||
"--mysql" => Box::new(MySqlDialect {}),
|
||||
"--snowflake" => Box::new(SnowflakeDialect {}),
|
||||
"--hive" => Box::new(HiveDialect {}),
|
||||
"--generic" | "" => Box::new(GenericDialect {}),
|
||||
|
|
|
@ -60,6 +60,13 @@ pub enum AlterTableOperation {
|
|||
},
|
||||
/// `RENAME TO <table_name>`
|
||||
RenameTable { table_name: ObjectName },
|
||||
// CHANGE [ COLUMN ] <old_name> <new_name> <data_type> [ <options> ]
|
||||
ChangeColumn {
|
||||
old_name: Ident,
|
||||
new_name: Ident,
|
||||
data_type: DataType,
|
||||
options: Vec<ColumnOption>,
|
||||
},
|
||||
}
|
||||
|
||||
impl fmt::Display for AlterTableOperation {
|
||||
|
@ -119,6 +126,19 @@ impl fmt::Display for AlterTableOperation {
|
|||
AlterTableOperation::RenameTable { table_name } => {
|
||||
write!(f, "RENAME TO {}", table_name)
|
||||
}
|
||||
AlterTableOperation::ChangeColumn {
|
||||
old_name,
|
||||
new_name,
|
||||
data_type,
|
||||
options,
|
||||
} => {
|
||||
write!(f, "CHANGE COLUMN {} {} {}", old_name, new_name, data_type)?;
|
||||
if options.is_empty() {
|
||||
Ok(())
|
||||
} else {
|
||||
write!(f, " {}", display_separated(options, " "))
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
|
|
@ -650,6 +650,7 @@ pub enum Statement {
|
|||
after_columns: Vec<Ident>,
|
||||
/// whether the insert has the table keyword (Hive)
|
||||
table: bool,
|
||||
on: Option<OnInsert>,
|
||||
},
|
||||
// TODO: Support ROW FORMAT
|
||||
Directory {
|
||||
|
@ -670,7 +671,7 @@ pub enum Statement {
|
|||
/// UPDATE
|
||||
Update {
|
||||
/// TABLE
|
||||
table_name: ObjectName,
|
||||
table: TableWithJoins,
|
||||
/// Column assignments
|
||||
assignments: Vec<Assignment>,
|
||||
/// WHERE
|
||||
|
@ -990,6 +991,7 @@ impl fmt::Display for Statement {
|
|||
after_columns,
|
||||
source,
|
||||
table,
|
||||
on,
|
||||
} => {
|
||||
if let Some(action) = or {
|
||||
write!(f, "INSERT OR {} INTO {} ", action, table_name)?;
|
||||
|
@ -1013,7 +1015,13 @@ impl fmt::Display for Statement {
|
|||
if !after_columns.is_empty() {
|
||||
write!(f, "({}) ", display_comma_separated(after_columns))?;
|
||||
}
|
||||
write!(f, "{}", source)
|
||||
write!(f, "{}", source)?;
|
||||
|
||||
if let Some(on) = on {
|
||||
write!(f, "{}", on)
|
||||
} else {
|
||||
Ok(())
|
||||
}
|
||||
}
|
||||
|
||||
Statement::Copy {
|
||||
|
@ -1042,11 +1050,11 @@ impl fmt::Display for Statement {
|
|||
write!(f, "\n\\.")
|
||||
}
|
||||
Statement::Update {
|
||||
table_name,
|
||||
table,
|
||||
assignments,
|
||||
selection,
|
||||
} => {
|
||||
write!(f, "UPDATE {}", table_name)?;
|
||||
write!(f, "UPDATE {}", table)?;
|
||||
if !assignments.is_empty() {
|
||||
write!(f, " SET {}", display_comma_separated(assignments))?;
|
||||
}
|
||||
|
@ -1452,6 +1460,26 @@ impl fmt::Display for Statement {
|
|||
}
|
||||
}
|
||||
|
||||
#[derive(Debug, Clone, PartialEq, Eq, Hash)]
|
||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||
#[non_exhaustive]
|
||||
pub enum OnInsert {
|
||||
/// ON DUPLICATE KEY UPDATE (MySQL when the key already exists, then execute an update instead)
|
||||
DuplicateKeyUpdate(Vec<Assignment>),
|
||||
}
|
||||
|
||||
impl fmt::Display for OnInsert {
|
||||
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
|
||||
match self {
|
||||
Self::DuplicateKeyUpdate(expr) => write!(
|
||||
f,
|
||||
" ON DUPLICATE KEY UPDATE {}",
|
||||
display_comma_separated(expr)
|
||||
),
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/// Privileges granted in a GRANT statement or revoked in a REVOKE statement.
|
||||
#[derive(Debug, Clone, PartialEq, Eq, Hash)]
|
||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||
|
@ -1587,13 +1615,13 @@ impl fmt::Display for GrantObjects {
|
|||
#[derive(Debug, Clone, PartialEq, Eq, Hash)]
|
||||
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
|
||||
pub struct Assignment {
|
||||
pub id: Ident,
|
||||
pub id: Vec<Ident>,
|
||||
pub value: Expr,
|
||||
}
|
||||
|
||||
impl fmt::Display for Assignment {
|
||||
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
|
||||
write!(f, "{} = {}", self.id, self.value)
|
||||
write!(f, "{} = {}", display_separated(&self.id, "."), self.value)
|
||||
}
|
||||
}
|
||||
|
||||
|
|
|
@ -114,6 +114,7 @@ define_keywords!(
|
|||
CEIL,
|
||||
CEILING,
|
||||
CHAIN,
|
||||
CHANGE,
|
||||
CHAR,
|
||||
CHARACTER,
|
||||
CHARACTER_LENGTH,
|
||||
|
@ -181,6 +182,7 @@ define_keywords!(
|
|||
DISTRIBUTE,
|
||||
DOUBLE,
|
||||
DROP,
|
||||
DUPLICATE,
|
||||
DYNAMIC,
|
||||
EACH,
|
||||
ELEMENT,
|
||||
|
@ -542,6 +544,7 @@ pub const RESERVED_FOR_TABLE_ALIAS: &[Keyword] = &[
|
|||
Keyword::DISTRIBUTE,
|
||||
// for MSSQL-specific OUTER APPLY (seems reserved in most dialects)
|
||||
Keyword::OUTER,
|
||||
Keyword::SET,
|
||||
];
|
||||
|
||||
/// Can't be used as a column alias, so that `SELECT <expr> alias`
|
||||
|
|
|
@ -702,11 +702,12 @@ impl<'a> Parser<'a> {
|
|||
self.expect_token(&Token::LParen)?;
|
||||
let expr = self.parse_expr()?;
|
||||
let mut from_expr = None;
|
||||
let mut to_expr = None;
|
||||
if self.parse_keyword(Keyword::FROM) {
|
||||
if self.parse_keyword(Keyword::FROM) || self.consume_token(&Token::Comma) {
|
||||
from_expr = Some(self.parse_expr()?);
|
||||
}
|
||||
if self.parse_keyword(Keyword::FOR) {
|
||||
|
||||
let mut to_expr = None;
|
||||
if self.parse_keyword(Keyword::FOR) || self.consume_token(&Token::Comma) {
|
||||
to_expr = Some(self.parse_expr()?);
|
||||
}
|
||||
self.expect_token(&Token::RParen)?;
|
||||
|
@ -1958,6 +1959,22 @@ impl<'a> Parser<'a> {
|
|||
old_partitions: before,
|
||||
new_partitions: renames,
|
||||
}
|
||||
} else if self.parse_keyword(Keyword::CHANGE) {
|
||||
let _ = self.parse_keyword(Keyword::COLUMN);
|
||||
let old_name = self.parse_identifier()?;
|
||||
let new_name = self.parse_identifier()?;
|
||||
let data_type = self.parse_data_type()?;
|
||||
let mut options = vec![];
|
||||
while let Some(option) = self.parse_optional_column_option()? {
|
||||
options.push(option);
|
||||
}
|
||||
|
||||
AlterTableOperation::ChangeColumn {
|
||||
old_name,
|
||||
new_name,
|
||||
data_type,
|
||||
options,
|
||||
}
|
||||
} else {
|
||||
return self.expected(
|
||||
"ADD, RENAME, PARTITION or DROP after ALTER TABLE",
|
||||
|
@ -2234,16 +2251,41 @@ impl<'a> Parser<'a> {
|
|||
Ok(ObjectName(idents))
|
||||
}
|
||||
|
||||
/// Parse identifiers strictly i.e. don't parse keywords
|
||||
pub fn parse_identifiers_non_keywords(&mut self) -> Result<Vec<Ident>, ParserError> {
|
||||
let mut idents = vec![];
|
||||
loop {
|
||||
match self.peek_token() {
|
||||
Token::Word(w) => {
|
||||
if w.keyword != Keyword::NoKeyword {
|
||||
break;
|
||||
}
|
||||
|
||||
idents.push(w.to_ident());
|
||||
}
|
||||
Token::EOF | Token::Eq => break,
|
||||
_ => {}
|
||||
}
|
||||
|
||||
self.next_token();
|
||||
}
|
||||
|
||||
Ok(idents)
|
||||
}
|
||||
|
||||
/// Parse identifiers
|
||||
pub fn parse_identifiers(&mut self) -> Result<Vec<Ident>, ParserError> {
|
||||
let mut idents = vec![];
|
||||
loop {
|
||||
match self.next_token() {
|
||||
Token::Word(w) => idents.push(w.to_ident()),
|
||||
Token::Word(w) => {
|
||||
idents.push(w.to_ident());
|
||||
}
|
||||
Token::EOF => break,
|
||||
_ => {}
|
||||
}
|
||||
}
|
||||
|
||||
Ok(idents)
|
||||
}
|
||||
|
||||
|
@ -2386,6 +2428,7 @@ impl<'a> Parser<'a> {
|
|||
})
|
||||
} else {
|
||||
let insert = self.parse_insert()?;
|
||||
|
||||
Ok(Query {
|
||||
with,
|
||||
body: SetExpr::Insert(insert),
|
||||
|
@ -3145,6 +3188,17 @@ impl<'a> Parser<'a> {
|
|||
let after_columns = self.parse_parenthesized_column_list(Optional)?;
|
||||
|
||||
let source = Box::new(self.parse_query()?);
|
||||
let on = if self.parse_keyword(Keyword::ON) {
|
||||
self.expect_keyword(Keyword::DUPLICATE)?;
|
||||
self.expect_keyword(Keyword::KEY)?;
|
||||
self.expect_keyword(Keyword::UPDATE)?;
|
||||
let l = self.parse_comma_separated(Parser::parse_assignment)?;
|
||||
|
||||
Some(OnInsert::DuplicateKeyUpdate(l))
|
||||
} else {
|
||||
None
|
||||
};
|
||||
|
||||
Ok(Statement::Insert {
|
||||
or,
|
||||
table_name,
|
||||
|
@ -3154,12 +3208,13 @@ impl<'a> Parser<'a> {
|
|||
after_columns,
|
||||
source,
|
||||
table,
|
||||
on,
|
||||
})
|
||||
}
|
||||
}
|
||||
|
||||
pub fn parse_update(&mut self) -> Result<Statement, ParserError> {
|
||||
let table_name = self.parse_object_name()?;
|
||||
let table = self.parse_table_and_joins()?;
|
||||
self.expect_keyword(Keyword::SET)?;
|
||||
let assignments = self.parse_comma_separated(Parser::parse_assignment)?;
|
||||
let selection = if self.parse_keyword(Keyword::WHERE) {
|
||||
|
@ -3168,7 +3223,7 @@ impl<'a> Parser<'a> {
|
|||
None
|
||||
};
|
||||
Ok(Statement::Update {
|
||||
table_name,
|
||||
table,
|
||||
assignments,
|
||||
selection,
|
||||
})
|
||||
|
@ -3176,7 +3231,7 @@ impl<'a> Parser<'a> {
|
|||
|
||||
/// Parse a `var = expr` assignment, used in an UPDATE statement
|
||||
pub fn parse_assignment(&mut self) -> Result<Assignment, ParserError> {
|
||||
let id = self.parse_identifier()?;
|
||||
let id = self.parse_identifiers_non_keywords()?;
|
||||
self.expect_token(&Token::Eq)?;
|
||||
let value = self.parse_expr()?;
|
||||
Ok(Assignment { id, value })
|
||||
|
|
|
@ -141,25 +141,25 @@ fn parse_update() {
|
|||
let sql = "UPDATE t SET a = 1, b = 2, c = 3 WHERE d";
|
||||
match verified_stmt(sql) {
|
||||
Statement::Update {
|
||||
table_name,
|
||||
table,
|
||||
assignments,
|
||||
selection,
|
||||
..
|
||||
} => {
|
||||
assert_eq!(table_name.to_string(), "t".to_string());
|
||||
assert_eq!(table.to_string(), "t".to_string());
|
||||
assert_eq!(
|
||||
assignments,
|
||||
vec![
|
||||
Assignment {
|
||||
id: "a".into(),
|
||||
id: vec!["a".into()],
|
||||
value: Expr::Value(number("1")),
|
||||
},
|
||||
Assignment {
|
||||
id: "b".into(),
|
||||
id: vec!["b".into()],
|
||||
value: Expr::Value(number("2")),
|
||||
},
|
||||
Assignment {
|
||||
id: "c".into(),
|
||||
id: vec!["c".into()],
|
||||
value: Expr::Value(number("3")),
|
||||
},
|
||||
]
|
||||
|
@ -186,6 +186,55 @@ fn parse_update() {
|
|||
);
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_update_with_table_alias() {
|
||||
let sql = "UPDATE users AS u SET u.username = 'new_user' WHERE u.username = 'old_user'";
|
||||
match verified_stmt(sql) {
|
||||
Statement::Update {
|
||||
table,
|
||||
assignments,
|
||||
selection,
|
||||
} => {
|
||||
assert_eq!(
|
||||
TableWithJoins {
|
||||
relation: TableFactor::Table {
|
||||
name: ObjectName(vec![Ident::new("users")]),
|
||||
alias: Some(TableAlias {
|
||||
name: Ident::new("u"),
|
||||
columns: vec![]
|
||||
}),
|
||||
args: vec![],
|
||||
with_hints: vec![],
|
||||
},
|
||||
joins: vec![]
|
||||
},
|
||||
table
|
||||
);
|
||||
assert_eq!(
|
||||
vec![Assignment {
|
||||
id: vec![Ident::new("u"), Ident::new("username")],
|
||||
value: Expr::Value(Value::SingleQuotedString("new_user".to_string()))
|
||||
}],
|
||||
assignments
|
||||
);
|
||||
assert_eq!(
|
||||
Some(Expr::BinaryOp {
|
||||
left: Box::new(Expr::CompoundIdentifier(vec![
|
||||
Ident::new("u"),
|
||||
Ident::new("username")
|
||||
])),
|
||||
op: BinaryOperator::Eq,
|
||||
right: Box::new(Expr::Value(Value::SingleQuotedString(
|
||||
"old_user".to_string()
|
||||
)))
|
||||
}),
|
||||
selection
|
||||
);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_invalid_table_name() {
|
||||
let ast = all_dialects()
|
||||
|
|
|
@ -216,6 +216,321 @@ fn parse_create_table_with_minimum_display_width() {
|
|||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
#[cfg(not(feature = "bigdecimal"))]
|
||||
fn parse_simple_insert() {
|
||||
let sql = r"INSERT INTO tasks (title, priority) VALUES ('Test Some Inserts', 1), ('Test Entry 2', 2), ('Test Entry 3', 3)";
|
||||
|
||||
match mysql().verified_stmt(sql) {
|
||||
Statement::Insert {
|
||||
table_name,
|
||||
columns,
|
||||
source,
|
||||
on,
|
||||
..
|
||||
} => {
|
||||
assert_eq!(ObjectName(vec![Ident::new("tasks")]), table_name);
|
||||
assert_eq!(vec![Ident::new("title"), Ident::new("priority")], columns);
|
||||
assert!(on.is_none());
|
||||
assert_eq!(
|
||||
Box::new(Query {
|
||||
with: None,
|
||||
body: SetExpr::Values(Values(vec![
|
||||
vec![
|
||||
Expr::Value(Value::SingleQuotedString("Test Some Inserts".to_string())),
|
||||
Expr::Value(Value::Number("1".to_string(), false))
|
||||
],
|
||||
vec![
|
||||
Expr::Value(Value::SingleQuotedString("Test Entry 2".to_string())),
|
||||
Expr::Value(Value::Number("2".to_string(), false))
|
||||
],
|
||||
vec![
|
||||
Expr::Value(Value::SingleQuotedString("Test Entry 3".to_string())),
|
||||
Expr::Value(Value::Number("3".to_string(), false))
|
||||
]
|
||||
])),
|
||||
order_by: vec![],
|
||||
limit: None,
|
||||
offset: None,
|
||||
fetch: None,
|
||||
}),
|
||||
source
|
||||
);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_insert_with_on_duplicate_update() {
|
||||
let sql = "INSERT INTO permission_groups (name, description, perm_create, perm_read, perm_update, perm_delete) VALUES ('accounting_manager', 'Some description about the group', true, true, true, true) ON DUPLICATE KEY UPDATE description = VALUES(description), perm_create = VALUES(perm_create), perm_read = VALUES(perm_read), perm_update = VALUES(perm_update), perm_delete = VALUES(perm_delete)";
|
||||
|
||||
match mysql().verified_stmt(sql) {
|
||||
Statement::Insert {
|
||||
table_name,
|
||||
columns,
|
||||
source,
|
||||
on,
|
||||
..
|
||||
} => {
|
||||
assert_eq!(
|
||||
ObjectName(vec![Ident::new("permission_groups")]),
|
||||
table_name
|
||||
);
|
||||
assert_eq!(
|
||||
vec![
|
||||
Ident::new("name"),
|
||||
Ident::new("description"),
|
||||
Ident::new("perm_create"),
|
||||
Ident::new("perm_read"),
|
||||
Ident::new("perm_update"),
|
||||
Ident::new("perm_delete")
|
||||
],
|
||||
columns
|
||||
);
|
||||
assert_eq!(
|
||||
Box::new(Query {
|
||||
with: None,
|
||||
body: SetExpr::Values(Values(vec![vec![
|
||||
Expr::Value(Value::SingleQuotedString("accounting_manager".to_string())),
|
||||
Expr::Value(Value::SingleQuotedString(
|
||||
"Some description about the group".to_string()
|
||||
)),
|
||||
Expr::Value(Value::Boolean(true)),
|
||||
Expr::Value(Value::Boolean(true)),
|
||||
Expr::Value(Value::Boolean(true)),
|
||||
Expr::Value(Value::Boolean(true)),
|
||||
]])),
|
||||
order_by: vec![],
|
||||
limit: None,
|
||||
offset: None,
|
||||
fetch: None,
|
||||
}),
|
||||
source
|
||||
);
|
||||
assert_eq!(
|
||||
Some(OnInsert::DuplicateKeyUpdate(vec![
|
||||
Assignment {
|
||||
id: vec![Ident::new("description".to_string())],
|
||||
value: Expr::Function(Function {
|
||||
name: ObjectName(vec![Ident::new("VALUES".to_string()),]),
|
||||
args: vec![FunctionArg::Unnamed(Expr::Identifier(Ident::new(
|
||||
"description"
|
||||
)))],
|
||||
over: None,
|
||||
distinct: false
|
||||
})
|
||||
},
|
||||
Assignment {
|
||||
id: vec![Ident::new("perm_create".to_string())],
|
||||
value: Expr::Function(Function {
|
||||
name: ObjectName(vec![Ident::new("VALUES".to_string()),]),
|
||||
args: vec![FunctionArg::Unnamed(Expr::Identifier(Ident::new(
|
||||
"perm_create"
|
||||
)))],
|
||||
over: None,
|
||||
distinct: false
|
||||
})
|
||||
},
|
||||
Assignment {
|
||||
id: vec![Ident::new("perm_read".to_string())],
|
||||
value: Expr::Function(Function {
|
||||
name: ObjectName(vec![Ident::new("VALUES".to_string()),]),
|
||||
args: vec![FunctionArg::Unnamed(Expr::Identifier(Ident::new(
|
||||
"perm_read"
|
||||
)))],
|
||||
over: None,
|
||||
distinct: false
|
||||
})
|
||||
},
|
||||
Assignment {
|
||||
id: vec![Ident::new("perm_update".to_string())],
|
||||
value: Expr::Function(Function {
|
||||
name: ObjectName(vec![Ident::new("VALUES".to_string()),]),
|
||||
args: vec![FunctionArg::Unnamed(Expr::Identifier(Ident::new(
|
||||
"perm_update"
|
||||
)))],
|
||||
over: None,
|
||||
distinct: false
|
||||
})
|
||||
},
|
||||
Assignment {
|
||||
id: vec![Ident::new("perm_delete".to_string())],
|
||||
value: Expr::Function(Function {
|
||||
name: ObjectName(vec![Ident::new("VALUES".to_string()),]),
|
||||
args: vec![FunctionArg::Unnamed(Expr::Identifier(Ident::new(
|
||||
"perm_delete"
|
||||
)))],
|
||||
over: None,
|
||||
distinct: false
|
||||
})
|
||||
},
|
||||
])),
|
||||
on
|
||||
);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_update_with_joins() {
|
||||
let sql = "UPDATE orders AS o JOIN customers AS c ON o.customer_id = c.id SET o.completed = true WHERE c.firstname = 'Peter'";
|
||||
match mysql().verified_stmt(sql) {
|
||||
Statement::Update {
|
||||
table,
|
||||
assignments,
|
||||
selection,
|
||||
} => {
|
||||
assert_eq!(
|
||||
TableWithJoins {
|
||||
relation: TableFactor::Table {
|
||||
name: ObjectName(vec![Ident::new("orders")]),
|
||||
alias: Some(TableAlias {
|
||||
name: Ident::new("o"),
|
||||
columns: vec![]
|
||||
}),
|
||||
args: vec![],
|
||||
with_hints: vec![],
|
||||
},
|
||||
joins: vec![Join {
|
||||
relation: TableFactor::Table {
|
||||
name: ObjectName(vec![Ident::new("customers")]),
|
||||
alias: Some(TableAlias {
|
||||
name: Ident::new("c"),
|
||||
columns: vec![]
|
||||
}),
|
||||
args: vec![],
|
||||
with_hints: vec![],
|
||||
},
|
||||
join_operator: JoinOperator::Inner(JoinConstraint::On(Expr::BinaryOp {
|
||||
left: Box::new(Expr::CompoundIdentifier(vec![
|
||||
Ident::new("o"),
|
||||
Ident::new("customer_id")
|
||||
])),
|
||||
op: BinaryOperator::Eq,
|
||||
right: Box::new(Expr::CompoundIdentifier(vec![
|
||||
Ident::new("c"),
|
||||
Ident::new("id")
|
||||
]))
|
||||
})),
|
||||
}]
|
||||
},
|
||||
table
|
||||
);
|
||||
assert_eq!(
|
||||
vec![Assignment {
|
||||
id: vec![Ident::new("o"), Ident::new("completed")],
|
||||
value: Expr::Value(Value::Boolean(true))
|
||||
}],
|
||||
assignments
|
||||
);
|
||||
assert_eq!(
|
||||
Some(Expr::BinaryOp {
|
||||
left: Box::new(Expr::CompoundIdentifier(vec![
|
||||
Ident::new("c"),
|
||||
Ident::new("firstname")
|
||||
])),
|
||||
op: BinaryOperator::Eq,
|
||||
right: Box::new(Expr::Value(Value::SingleQuotedString("Peter".to_string())))
|
||||
}),
|
||||
selection
|
||||
);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
fn parse_alter_table_change_column() {
|
||||
let expected_name = ObjectName(vec![Ident::new("orders")]);
|
||||
let expected_operation = AlterTableOperation::ChangeColumn {
|
||||
old_name: Ident::new("description"),
|
||||
new_name: Ident::new("desc"),
|
||||
data_type: DataType::Text,
|
||||
options: vec![ColumnOption::NotNull],
|
||||
};
|
||||
|
||||
let sql1 = "ALTER TABLE orders CHANGE COLUMN description desc TEXT NOT NULL";
|
||||
match mysql().verified_stmt(sql1) {
|
||||
Statement::AlterTable { name, operation } => {
|
||||
assert_eq!(expected_name, name);
|
||||
assert_eq!(expected_operation, operation);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
|
||||
let sql2 = "ALTER TABLE orders CHANGE description desc TEXT NOT NULL";
|
||||
match mysql().one_statement_parses_to(sql2, sql1) {
|
||||
Statement::AlterTable { name, operation } => {
|
||||
assert_eq!(expected_name, name);
|
||||
assert_eq!(expected_operation, operation);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
#[test]
|
||||
#[cfg(not(feature = "bigdecimal"))]
|
||||
fn parse_substring_in_select() {
|
||||
let sql = "SELECT DISTINCT SUBSTRING(description, 0, 1) FROM test";
|
||||
match mysql().one_statement_parses_to(
|
||||
sql,
|
||||
"SELECT DISTINCT SUBSTRING(description FROM 0 FOR 1) FROM test",
|
||||
) {
|
||||
Statement::Query(query) => {
|
||||
assert_eq!(
|
||||
Box::new(Query {
|
||||
with: None,
|
||||
body: SetExpr::Select(Box::new(Select {
|
||||
distinct: true,
|
||||
top: None,
|
||||
projection: vec![SelectItem::UnnamedExpr(Expr::Substring {
|
||||
expr: Box::new(Expr::Identifier(Ident {
|
||||
value: "description".to_string(),
|
||||
quote_style: None
|
||||
})),
|
||||
substring_from: Some(Box::new(Expr::Value(Value::Number(
|
||||
"0".to_string(),
|
||||
false
|
||||
)))),
|
||||
substring_for: Some(Box::new(Expr::Value(Value::Number(
|
||||
"1".to_string(),
|
||||
false
|
||||
))))
|
||||
})],
|
||||
from: vec![TableWithJoins {
|
||||
relation: TableFactor::Table {
|
||||
name: ObjectName(vec![Ident {
|
||||
value: "test".to_string(),
|
||||
quote_style: None
|
||||
}]),
|
||||
alias: None,
|
||||
args: vec![],
|
||||
with_hints: vec![]
|
||||
},
|
||||
joins: vec![]
|
||||
}],
|
||||
lateral_views: vec![],
|
||||
selection: None,
|
||||
group_by: vec![],
|
||||
cluster_by: vec![],
|
||||
distribute_by: vec![],
|
||||
sort_by: vec![],
|
||||
having: None,
|
||||
})),
|
||||
order_by: vec![],
|
||||
limit: None,
|
||||
offset: None,
|
||||
fetch: None
|
||||
}),
|
||||
query
|
||||
);
|
||||
}
|
||||
_ => unreachable!(),
|
||||
}
|
||||
}
|
||||
|
||||
fn mysql() -> TestedDialects {
|
||||
TestedDialects {
|
||||
dialects: vec![Box::new(MySqlDialect {})],
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue