Skip to content

MSSQL: Add support for functionality MERGE output clause #1790

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 20 commits into from
Apr 5, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
39 changes: 38 additions & 1 deletion src/ast/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -3817,6 +3817,7 @@ pub enum Statement {
/// ```
/// [Snowflake](https://docs.snowflake.com/en/sql-reference/sql/merge)
/// [BigQuery](https://cloud.google.com/bigquery/docs/reference/standard-sql/dml-syntax#merge_statement)
/// [MSSQL](https://learn.microsoft.com/en-us/sql/t-sql/statements/merge-transact-sql?view=sql-server-ver16)
Merge {
/// optional INTO keyword
into: bool,
Expand All @@ -3828,6 +3829,8 @@ pub enum Statement {
on: Box<Expr>,
/// Specifies the actions to perform when values match or do not match.
clauses: Vec<MergeClause>,
// Specifies the output to save changes in MSSQL
output: Option<OutputClause>,
},
/// ```sql
/// CACHE [ FLAG ] TABLE <table_name> [ OPTIONS('K1' = 'V1', 'K2' = V2) ] [ AS ] [ <query> ]
Expand Down Expand Up @@ -5407,14 +5410,19 @@ impl fmt::Display for Statement {
source,
on,
clauses,
output,
} => {
write!(
f,
"MERGE{int} {table} USING {source} ",
int = if *into { " INTO" } else { "" }
)?;
write!(f, "ON {on} ")?;
write!(f, "{}", display_separated(clauses, " "))
write!(f, "{}", display_separated(clauses, " "))?;
if let Some(output) = output {
write!(f, " {output}")?;
}
Ok(())
}
Statement::Cache {
table_name,
Expand Down Expand Up @@ -7945,6 +7953,35 @@ impl Display for MergeClause {
}
}

/// A Output Clause in the end of a 'MERGE' Statement
///
/// Example:
/// OUTPUT $action, deleted.* INTO dbo.temp_products;
/// [mssql](https://learn.microsoft.com/en-us/sql/t-sql/queries/output-clause-transact-sql)
#[derive(Debug, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
pub struct OutputClause {
pub select_items: Vec<SelectItem>,
pub into_table: SelectInto,
}

impl fmt::Display for OutputClause {
fn fmt(&self, f: &mut fmt::Formatter) -> fmt::Result {
let OutputClause {
select_items,
into_table,
} = self;

write!(
f,
"OUTPUT {} {}",
display_comma_separated(select_items),
into_table
)
}
}

#[derive(Debug, Copy, Clone, PartialEq, PartialOrd, Eq, Ord, Hash)]
#[cfg_attr(feature = "serde", derive(Serialize, Deserialize))]
#[cfg_attr(feature = "visitor", derive(Visit, VisitMut))]
Expand Down
1 change: 1 addition & 0 deletions src/keywords.rs
Original file line number Diff line number Diff line change
Expand Up @@ -632,6 +632,7 @@ define_keywords!(
ORGANIZATION,
OUT,
OUTER,
OUTPUT,
OUTPUTFORMAT,
OVER,
OVERFLOW,
Expand Down
50 changes: 36 additions & 14 deletions src/parser/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -10910,18 +10910,7 @@ impl<'a> Parser<'a> {
};

let into = if self.parse_keyword(Keyword::INTO) {
let temporary = self
.parse_one_of_keywords(&[Keyword::TEMP, Keyword::TEMPORARY])
.is_some();
let unlogged = self.parse_keyword(Keyword::UNLOGGED);
let table = self.parse_keyword(Keyword::TABLE);
let name = self.parse_object_name(false)?;
Some(SelectInto {
temporary,
unlogged,
table,
name,
})
Some(self.parse_select_into()?)
} else {
None
};
Expand Down Expand Up @@ -14513,10 +14502,9 @@ impl<'a> Parser<'a> {
pub fn parse_merge_clauses(&mut self) -> Result<Vec<MergeClause>, ParserError> {
let mut clauses = vec![];
loop {
if self.peek_token() == Token::EOF || self.peek_token() == Token::SemiColon {
if !(self.parse_keyword(Keyword::WHEN)) {
break;
}
self.expect_keyword_is(Keyword::WHEN)?;

let mut clause_kind = MergeClauseKind::Matched;
if self.parse_keyword(Keyword::NOT) {
Expand Down Expand Up @@ -14610,6 +14598,34 @@ impl<'a> Parser<'a> {
Ok(clauses)
}

fn parse_output(&mut self) -> Result<OutputClause, ParserError> {
self.expect_keyword_is(Keyword::OUTPUT)?;
let select_items = self.parse_projection()?;
self.expect_keyword_is(Keyword::INTO)?;
let into_table = self.parse_select_into()?;

Ok(OutputClause {
select_items,
into_table,
})
}

fn parse_select_into(&mut self) -> Result<SelectInto, ParserError> {
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

oh could we also update this usage to call this parse_select_into() function as well?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

good idea, I've changed it to use the new function!

let temporary = self
.parse_one_of_keywords(&[Keyword::TEMP, Keyword::TEMPORARY])
.is_some();
let unlogged = self.parse_keyword(Keyword::UNLOGGED);
let table = self.parse_keyword(Keyword::TABLE);
let name = self.parse_object_name(false)?;

Ok(SelectInto {
temporary,
unlogged,
table,
name,
})
}

pub fn parse_merge(&mut self) -> Result<Statement, ParserError> {
let into = self.parse_keyword(Keyword::INTO);

Expand All @@ -14620,13 +14636,19 @@ impl<'a> Parser<'a> {
self.expect_keyword_is(Keyword::ON)?;
let on = self.parse_expr()?;
let clauses = self.parse_merge_clauses()?;
let output = if self.peek_keyword(Keyword::OUTPUT) {
Some(self.parse_output()?)
} else {
None
};

Ok(Statement::Merge {
into,
table,
source,
on: Box::new(on),
clauses,
output,
})
}

Expand Down
2 changes: 2 additions & 0 deletions tests/sqlparser_bigquery.rs
Original file line number Diff line number Diff line change
Expand Up @@ -1735,13 +1735,15 @@ fn parse_merge() {
},
],
};

match bigquery_and_generic().verified_stmt(sql) {
Statement::Merge {
into,
table,
source,
on,
clauses,
..
} => {
assert!(!into);
assert_eq!(
Expand Down
15 changes: 15 additions & 0 deletions tests/sqlparser_common.rs
Original file line number Diff line number Diff line change
Expand Up @@ -9359,13 +9359,15 @@ fn parse_merge() {
source,
on,
clauses,
..
},
Statement::Merge {
into: no_into,
table: table_no_into,
source: source_no_into,
on: on_no_into,
clauses: clauses_no_into,
..
},
) => {
assert!(into);
Expand Down Expand Up @@ -9558,6 +9560,19 @@ fn parse_merge() {
verified_stmt(sql);
}

#[test]
fn test_merge_with_output() {
let sql = "MERGE INTO target_table USING source_table \
ON target_table.id = source_table.oooid \
WHEN MATCHED THEN \
UPDATE SET target_table.description = source_table.description \
WHEN NOT MATCHED THEN \
INSERT (ID, description) VALUES (source_table.id, source_table.description) \
OUTPUT inserted.* INTO log_target";

verified_stmt(sql);
}

#[test]
fn test_merge_into_using_table() {
let sql = "MERGE INTO target_table USING source_table \
Expand Down
16 changes: 16 additions & 0 deletions tests/sqlparser_mssql.rs
Original file line number Diff line number Diff line change
Expand Up @@ -1921,3 +1921,19 @@ fn ms() -> TestedDialects {
fn ms_and_generic() -> TestedDialects {
TestedDialects::new(vec![Box::new(MsSqlDialect {}), Box::new(GenericDialect {})])
}

#[test]
fn parse_mssql_merge_with_output() {
let stmt = "MERGE dso.products AS t \
USING dsi.products AS \
s ON s.ProductID = t.ProductID \
WHEN MATCHED AND \
NOT (t.ProductName = s.ProductName OR (ISNULL(t.ProductName, s.ProductName) IS NULL)) \
THEN UPDATE SET t.ProductName = s.ProductName \
WHEN NOT MATCHED BY TARGET \
THEN INSERT (ProductID, ProductName) \
VALUES (s.ProductID, s.ProductName) \
WHEN NOT MATCHED BY SOURCE THEN DELETE \
OUTPUT $action, deleted.ProductID INTO dsi.temp_products";
ms_and_generic().verified_stmt(stmt);
}
2 changes: 1 addition & 1 deletion tests/sqlparser_redshift.rs
Original file line number Diff line number Diff line change
Expand Up @@ -395,5 +395,5 @@ fn test_parse_nested_quoted_identifier() {
#[test]
fn parse_extract_single_quotes() {
let sql = "SELECT EXTRACT('month' FROM my_timestamp) FROM my_table";
redshift().verified_stmt(&sql);
redshift().verified_stmt(sql);
}