提交 0c4ecec6 authored 作者: Noel Grandin's avatar Noel Grandin 提交者: GitHub

Merge pull request #626 from stumc/Issue#589

Issue#589 Support MERGE INTO ... USING syntax
...@@ -21,7 +21,7 @@ OFFSET specified how many rows to skip. ...@@ -21,7 +21,7 @@ OFFSET specified how many rows to skip.
Please note using high offset values should be avoided because it can cause performance problems. Please note using high offset values should be avoided because it can cause performance problems.
SAMPLE_SIZE limits the number of rows read for aggregate queries. SAMPLE_SIZE limits the number of rows read for aggregate queries.
Multiple set operators (UNION, INTERSECT, MINUS, EXPECT) are evaluated Multiple set operators (UNION, INTERSECT, MINUS, EXCEPT) are evaluated
from left to right. For compatibility with other databases and future versions from left to right. For compatibility with other databases and future versions
of H2 please use parentheses. of H2 please use parentheses.
...@@ -122,6 +122,37 @@ key is set to 0; otherwise it is set to the new key. ...@@ -122,6 +122,37 @@ key is set to 0; otherwise it is set to the new key.
MERGE INTO TEST KEY(ID) VALUES(2, 'World') MERGE INTO TEST KEY(ID) VALUES(2, 'World')
" "
"Commands (DML)","MERGE USING","
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
ON ( expression )
[ WHEN MATCHED THEN [ update ] [ delete] ]
[ WHEN NOT MATCHED THEN insert ]
","
Updates or deletes existing rows, and insert rows that don't exist. The ON clause
specifies the matching column expression and must be specified. If more than one row
is updated per input row, an exception is thrown.
If the source data contains duplicate rows (specifically those columns used in the
row matching ON clause), then an exception is thrown to prevent two updates applying
to the same target row. The embedded update, delete or insert statements can not re-specify
the target table name.
","
MERGE INTO TARGET_TABLE AS T USING SOURCE_TABLE AS S
ON (T.ID = S.ID)
WHEN MATCHED THEN
UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
DELETE WHERE T.COL2='FINAL'
WHEN NOT MATCHED THEN
INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
MERGE INTO TARGET_TABLE AS T USING (SELECT * FROM SOURCE_TABLE) AS S
ON (T.ID = S.ID)
WHEN MATCHED THEN
UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
DELETE WHERE T.COL2='FINAL'
WHEN NOT MATCHED THEN
INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
"
"Commands (DML)","RUNSCRIPT"," "Commands (DML)","RUNSCRIPT","
RUNSCRIPT FROM fileNameString scriptCompressionEncryption RUNSCRIPT FROM fileNameString scriptCompressionEncryption
[ CHARSET charsetString ] [ CHARSET charsetString ]
......
...@@ -13,6 +13,8 @@ import java.math.BigInteger; ...@@ -13,6 +13,8 @@ import java.math.BigInteger;
import java.nio.charset.Charset; import java.nio.charset.Charset;
import java.text.Collator; import java.text.Collator;
import java.util.ArrayList; import java.util.ArrayList;
import java.util.Arrays;
import java.util.Collection;
import java.util.Collections; import java.util.Collections;
import java.util.Comparator; import java.util.Comparator;
import java.util.HashSet; import java.util.HashSet;
...@@ -76,6 +78,7 @@ import org.h2.command.dml.ExecuteProcedure; ...@@ -76,6 +78,7 @@ import org.h2.command.dml.ExecuteProcedure;
import org.h2.command.dml.Explain; import org.h2.command.dml.Explain;
import org.h2.command.dml.Insert; import org.h2.command.dml.Insert;
import org.h2.command.dml.Merge; import org.h2.command.dml.Merge;
import org.h2.command.dml.MergeUsing;
import org.h2.command.dml.NoOperation; import org.h2.command.dml.NoOperation;
import org.h2.command.dml.Query; import org.h2.command.dml.Query;
import org.h2.command.dml.Replace; import org.h2.command.dml.Replace;
...@@ -698,6 +701,32 @@ public class Parser { ...@@ -698,6 +701,32 @@ public class Parser {
private Schema getSchema() { private Schema getSchema() {
return getSchema(schemaName); return getSchema(schemaName);
} }
/*
* Gets the current schema for scenarios that need a guranteed, non-null schema object.
*
* This routine is solely here
* because of the function readIdentifierWithSchema(String defaultSchemaName) - which
* is often called with a null parameter (defaultSchemaName) - then 6 lines into the function
* that routine nullifies the state field schemaName - which I believe is a bug.
*
* There are about 7 places where "readIdentifierWithSchema(null)" is called in this file.
*
* In other words when is it legal to not have an active schema defined by schemaName ?
* I don't think it's ever a valid case. I don't understand when that would be allowed.
* I spent a long time trying to figure this out.
* As another proof of this point, the command "SET SCHEMA=NULL" is not a valid command.
*
* I did try to fix this in readIdentifierWithSchema(String defaultSchemaName)
* - but every fix I tried cascaded so many unit test errors - so
* I gave up. I think this needs a bigger effort to fix his, as part of bigger, dedicated story.
*
*/
private Schema getSchemaWithDefault() {
if(schemaName==null){
schemaName = session.getCurrentSchemaName();
}
return getSchema(schemaName);
}
private Column readTableColumn(TableFilter filter) { private Column readTableColumn(TableFilter filter) {
String tableAlias = null; String tableAlias = null;
...@@ -743,6 +772,11 @@ public class Parser { ...@@ -743,6 +772,11 @@ public class Parser {
int start = lastParseIndex; int start = lastParseIndex;
TableFilter filter = readSimpleTableFilter(0); TableFilter filter = readSimpleTableFilter(0);
command.setTableFilter(filter); command.setTableFilter(filter);
parseUpdateSetClause(command, filter, start);
return command;
}
private void parseUpdateSetClause(Update command, TableFilter filter, int start) {
read("SET"); read("SET");
if (readIf("(")) { if (readIf("(")) {
ArrayList<Column> columns = New.arrayList(); ArrayList<Column> columns = New.arrayList();
...@@ -793,8 +827,7 @@ public class Parser { ...@@ -793,8 +827,7 @@ public class Parser {
Expression limit = readTerm().optimize(session); Expression limit = readTerm().optimize(session);
command.setLimit(limit); command.setLimit(limit);
} }
setSQL(command, "UPDATE", start); setSQL(command, "UPDATE", start);
return command;
} }
private TableFilter readSimpleTableFilter(int orderInFrom) { private TableFilter readSimpleTableFilter(int orderInFrom) {
...@@ -812,6 +845,21 @@ public class Parser { ...@@ -812,6 +845,21 @@ public class Parser {
currentSelect, orderInFrom, null); currentSelect, orderInFrom, null);
} }
private TableFilter readSimpleTableFilterWithAliasExcludes(int orderInFrom,Collection<String> excludeTokens) {
Table table = readTableOrView();
String alias = null;
if (readIf("AS")) {
alias = readAliasIdentifier();
} else if (currentTokenType == IDENTIFIER) {
if (!equalsTokenIgnoreCase(currentToken,"SET") && !isTokenInList(excludeTokens)) {
// SET is not a keyword (PostgreSQL supports it as a table name)
alias = readAliasIdentifier();
}
}
return new TableFilter(session, table, alias, rightsChecked,
currentSelect, orderInFrom, null);
}
private Delete parseDelete() { private Delete parseDelete() {
Delete command = new Delete(session); Delete command = new Delete(session);
Expression limit = null; Expression limit = null;
...@@ -826,6 +874,11 @@ public class Parser { ...@@ -826,6 +874,11 @@ public class Parser {
} }
TableFilter filter = readSimpleTableFilter(0); TableFilter filter = readSimpleTableFilter(0);
command.setTableFilter(filter); command.setTableFilter(filter);
parseDeleteGivenTable(command, limit, start);
return command;
}
private void parseDeleteGivenTable(Delete command, Expression limit, int start) {
if (readIf("WHERE")) { if (readIf("WHERE")) {
Expression condition = readExpression(); Expression condition = readExpression();
command.setCondition(condition); command.setCondition(condition);
...@@ -835,7 +888,6 @@ public class Parser { ...@@ -835,7 +888,6 @@ public class Parser {
} }
command.setLimit(limit); command.setLimit(limit);
setSQL(command, "DELETE", start); setSQL(command, "DELETE", start);
return command;
} }
private IndexColumn[] parseIndexColumnList() { private IndexColumn[] parseIndexColumnList() {
...@@ -1021,13 +1073,21 @@ public class Parser { ...@@ -1021,13 +1073,21 @@ public class Parser {
read(); read();
return select; return select;
} }
private Merge parseMerge() { private Prepared parseMerge() {
Merge command = new Merge(session); Merge command = new Merge(session);
currentPrepared = command; currentPrepared = command;
int start = lastParseIndex;
read("INTO"); read("INTO");
Table table = readTableOrView(); List<String> excludeIdentifiers = Arrays.asList("USING","KEY","VALUES");
command.setTable(table); TableFilter targetTableFilter = readSimpleTableFilterWithAliasExcludes(0,excludeIdentifiers);
command.setTargetTableFilter(targetTableFilter);
Table table = command.getTargetTable();
if (readIf("USING")){
return parseMergeUsing(command,start);
}
if (readIf("(")) { if (readIf("(")) {
if (isSelect()) { if (isSelect()) {
command.setQuery(parseSelect()); command.setQuery(parseSelect());
...@@ -1063,12 +1123,140 @@ public class Parser { ...@@ -1063,12 +1123,140 @@ public class Parser {
return command; return command;
} }
private MergeUsing parseMergeUsing(Merge oldCommand, int start) {
MergeUsing command = new MergeUsing(oldCommand);
currentPrepared = command;
if (readIf("(")) {
/* a select query is supplied */
if (isSelect()) {
command.setQuery(parseSelect());
read(")");
}
command.setQueryAlias(readFromAlias(null, Arrays.asList("ON")));
String[] querySQLOutput = new String[]{null};
List<Column> columnTemplateList = createQueryColumnTemplateList(null, command.getQuery(), querySQLOutput);
TableView temporarySourceTableView = createTemporarySessionView(command.getQueryAlias(), querySQLOutput[0], columnTemplateList, false/*no recursion*/, false/* do not add to session*/);
TableFilter sourceTableFilter = new TableFilter(session, temporarySourceTableView, command.getQueryAlias(), rightsChecked,
(Select) command.getQuery(), 0, null);
command.setSourceTableFilter(sourceTableFilter);
}
else{
/* Its a table name, simulate a query by building a select query for the table */
List<String> excludeIdentifiers = Arrays.asList("ON");
TableFilter sourceTableFilter = readSimpleTableFilterWithAliasExcludes(0,excludeIdentifiers);
command.setSourceTableFilter(sourceTableFilter);
StringBuilder buff = new StringBuilder(
"SELECT * FROM "+sourceTableFilter.getTable().getName());
if(sourceTableFilter.getTableAlias()!=null){
buff.append(" AS "+sourceTableFilter.getTableAlias());
}
Prepared preparedQuery = prepare(session, buff.toString(), null/*paramValues*/);
command.setQuery((Select)preparedQuery);
}
read("ON");
read("(");
Expression condition = readExpression();
command.setOnCondition(condition);
read(")");
if(readIfAll("WHEN","MATCHED","THEN")){
int startMatched = lastParseIndex;
if (readIf("UPDATE")){
Update updateCommand = new Update(session);
//currentPrepared = updateCommand;
TableFilter filter = command.getTargetTableFilter();
updateCommand.setTableFilter(filter);
parseUpdateSetClause(updateCommand, filter,startMatched);
command.setUpdateCommand(updateCommand);
}
startMatched = lastParseIndex;
if (readIf("DELETE")){
Delete deleteCommand = new Delete(session);
TableFilter filter = command.getTargetTableFilter();
deleteCommand.setTableFilter(filter);
parseDeleteGivenTable(deleteCommand,null,startMatched);
command.setDeleteCommand(deleteCommand);
}
}
if(readIfAll("WHEN","NOT","MATCHED","THEN")){
if (readIf("INSERT")){
Insert insertCommand = new Insert(session);
insertCommand.setTable(command.getTargetTable());
parseInsertGivenTable(insertCommand, command.getTargetTable());
command.setInsertCommand(insertCommand);
}
}
setSQL(command, "MERGE", start);
// build and prepare the targetMatchQuery ready to test each rows existence in the target table (using source row to match)
StringBuffer targetMatchQuerySQL = new StringBuffer("SELECT _ROWID_ FROM "+command.getTargetTable().getName());
if(command.getTargetTableFilter().getTableAlias()!=null){
targetMatchQuerySQL.append(" AS "+command.getTargetTableFilter().getTableAlias());
}
targetMatchQuerySQL.append(" WHERE "+command.getOnCondition().getSQL());
// Select preparedTargetMatchQuery = new Select(session);
// preparedTargetMatchQuery.addTableFilter(command.getTargetTableFilter(), true/*isTop*/);
// preparedTargetMatchQuery.addTableFilter(command.getSourceTableFilter(), false/*isTop - not top table scan*/);
// preparedTargetMatchQuery.setSQL(targetMatchQuerySQL.toString());
// ArrayList<Expression> selectList = New.arrayList();
// //Database db = session == null ? null : session.getDatabase();
// selectList.add(new ExpressionColumn(session.getDatabase(), command.getTargetTableFilter().getTable().getRowIdColumn()));
// preparedTargetMatchQuery.setExpressions(selectList);
// preparedTargetMatchQuery.init();
command.setTargetMatchQuery((Select)parse(targetMatchQuerySQL.toString()));
// Select command = new Select(session);
// currentSelect = command;
// TableFilter filter = parseValuesTable(0);
// ArrayList<Expression> list = New.arrayList();
// list.add(new Wildcard(null, null));
// command.setExpressions(list);
// command.addTableFilter(filter, true);
// command.init();
return command;
}
private Insert parseInsert() { private Insert parseInsert() {
Insert command = new Insert(session); Insert command = new Insert(session);
currentPrepared = command; currentPrepared = command;
read("INTO"); read("INTO");
Table table = readTableOrView(); Table table = readTableOrView();
command.setTable(table); command.setTable(table);
Insert returnedCommand = parseInsertGivenTable(command, table);
if (returnedCommand!=null){
return returnedCommand;
}
if (database.getMode().onDuplicateKeyUpdate) {
if (readIf("ON")) {
read("DUPLICATE");
read("KEY");
read("UPDATE");
do {
Column column = parseColumn(table);
read("=");
Expression expression;
if (readIf("DEFAULT")) {
expression = ValueExpression.getDefault();
} else {
expression = readExpression();
}
command.addAssignmentForDuplicate(column, expression);
} while (readIf(","));
}
}
if (database.getMode().isolationLevelInSelectOrInsertStatement) {
parseIsolationClause();
}
return command;
}
private Insert parseInsertGivenTable(Insert command, Table table) {
Column[] columns = null; Column[] columns = null;
if (readIf("(")) { if (readIf("(")) {
if (isSelect()) { if (isSelect()) {
...@@ -1127,28 +1315,7 @@ public class Parser { ...@@ -1127,28 +1315,7 @@ public class Parser {
} else { } else {
command.setQuery(parseSelect()); command.setQuery(parseSelect());
} }
if (database.getMode().onDuplicateKeyUpdate) { return null;
if (readIf("ON")) {
read("DUPLICATE");
read("KEY");
read("UPDATE");
do {
Column column = parseColumn(table);
read("=");
Expression expression;
if (readIf("DEFAULT")) {
expression = ValueExpression.getDefault();
} else {
expression = readExpression();
}
command.addAssignmentForDuplicate(column, expression);
} while (readIf(","));
}
}
if (database.getMode().isolationLevelInSelectOrInsertStatement) {
parseIsolationClause();
}
return command;
} }
/** /**
...@@ -1317,18 +1484,21 @@ public class Parser { ...@@ -1317,18 +1484,21 @@ public class Parser {
return IndexHints.createUseIndexHints(indexNames); return IndexHints.createUseIndexHints(indexNames);
} }
private String readFromAlias(String alias) { private String readFromAlias(String alias, List<String> excludeIdentifiers) {
if (readIf("AS")) { if (readIf("AS")) {
alias = readAliasIdentifier(); alias = readAliasIdentifier();
} else if (currentTokenType == IDENTIFIER) { } else if (currentTokenType == IDENTIFIER && !isTokenInList(excludeIdentifiers)) {
// left and right are not keywords (because they are functions as
// well)
if (!isToken("LEFT") && !isToken("RIGHT") && !isToken("FULL")) {
alias = readAliasIdentifier(); alias = readAliasIdentifier();
}
} }
return alias; return alias;
} }
private String readFromAlias(String alias) {
// left and right are not keywords (because they are functions as
// well)
List<String> excludeIdentifiers = Arrays.asList("LEFT","RIGHT","FULL");
return readFromAlias(alias, excludeIdentifiers);
}
private Prepared parseTruncate() { private Prepared parseTruncate() {
read("TABLE"); read("TABLE");
...@@ -1759,14 +1929,25 @@ public class Parser { ...@@ -1759,14 +1929,25 @@ public class Parser {
} }
private Query parseSelect() { private Query parseSelect() {
int paramIndex = parameters.size(); // This method and its subroutines sometimes resets the schema name - the try-finally block
Query command = parseSelectUnion(); // makes sure it is reverted if nulled
ArrayList<Parameter> params = New.arrayList(); //String savedSchemaName = schemaName;
for (int i = paramIndex, size = parameters.size(); i < size; i++) { Query command = null;
params.add(parameters.get(i)); //try{
} int paramIndex = parameters.size();
command.setParameterList(params); command = parseSelectUnion();
command.init(); ArrayList<Parameter> params = New.arrayList();
for (int i = paramIndex, size = parameters.size(); i < size; i++) {
params.add(parameters.get(i));
}
command.setParameterList(params);
command.init();
//}
//finally{
//if(schemaName==null){
// schemaName = savedSchemaName;
//}
//}
return command; return command;
} }
...@@ -3241,6 +3422,7 @@ public class Parser { ...@@ -3241,6 +3422,7 @@ public class Parser {
return s; return s;
} }
// TODO: why does this function allow defaultSchemaName=null - which resets the parser schemaName for everyone ?
private String readIdentifierWithSchema(String defaultSchemaName) { private String readIdentifierWithSchema(String defaultSchemaName) {
if (currentTokenType != IDENTIFIER) { if (currentTokenType != IDENTIFIER) {
throw DbException.getSyntaxError(sqlCommand, parseIndex, throw DbException.getSyntaxError(sqlCommand, parseIndex,
...@@ -3311,7 +3493,27 @@ public class Parser { ...@@ -3311,7 +3493,27 @@ public class Parser {
addExpected(token); addExpected(token);
return false; return false;
} }
/*
* Reads every token in list, in order - returns true if all are found.
* If any are not found, returns false - AND resets parsing back to state when called.
*/
private boolean readIfAll(String ... tokens) {
// save parse location in case we have to fail this test
int start = lastParseIndex;
for(String token: tokens){
if (!currentTokenQuoted && equalsToken(token, currentToken)) {
read();
}
else{
// read failed - revert parse location to before when called
parseIndex = start;
read();
return false;
}
}
return true;
}
private boolean isToken(String token) { private boolean isToken(String token) {
boolean result = equalsToken(token, currentToken) && boolean result = equalsToken(token, currentToken) &&
!currentTokenQuoted; !currentTokenQuoted;
...@@ -3332,6 +3534,22 @@ public class Parser { ...@@ -3332,6 +3534,22 @@ public class Parser {
} }
return false; return false;
} }
private boolean equalsTokenIgnoreCase(String a, String b) {
if (a == null) {
return b == null;
} else if (a.equals(b)) {
return true;
} else if (a.equalsIgnoreCase(b)) {
return true;
}
return false;
}
private boolean isTokenInList(Collection<String> upperCaseTokenList){
String upperCaseCurrentToken = currentToken.toUpperCase();
return upperCaseTokenList.contains(upperCaseCurrentToken);
}
private void addExpected(String token) { private void addExpected(String token) {
if (expectedList != null) { if (expectedList != null) {
...@@ -4988,7 +5206,7 @@ public class Parser { ...@@ -4988,7 +5206,7 @@ public class Parser {
if (readIf("(")) { if (readIf("(")) {
cols = parseColumnList(); cols = parseColumnList();
for (String c : cols) { for (String c : cols) {
// we dont really know the type of the column, so string will // we don't really know the type of the column, so string will
// have to do // have to do
columns.add(new Column(c, Value.STRING)); columns.add(new Column(c, Value.STRING));
} }
...@@ -5021,51 +5239,77 @@ public class Parser { ...@@ -5021,51 +5239,77 @@ public class Parser {
data.session = session; data.session = session;
recursiveTable = schema.createTable(data); recursiveTable = schema.createTable(data);
session.addLocalTempTable(recursiveTable); session.addLocalTempTable(recursiveTable);
String querySQL; List<Column> columnTemplateList;
List<Column> columnTemplateList = new ArrayList<>(); String[] querySQLOutput = new String[]{null};
try { try {
read("AS"); read("AS");
read("("); read("(");
Query withQuery = parseSelect(); Query withQuery = parseSelect();
read(")"); read(")");
withQuery.prepare(); columnTemplateList = createQueryColumnTemplateList(cols, withQuery, querySQLOutput);
querySQL = StringUtils.cache(withQuery.getPlanSQL());
ArrayList<Expression> withExpressions = withQuery.getExpressions();
for (int i = 0; i < withExpressions.size(); ++i) {
Expression columnExp = withExpressions.get(i);
// use the passed in column name if supplied, otherwise use alias (if used) otherwise use column name
// derived from column expression
String columnName;
if (cols != null){
columnName = cols[i];
} else if (columnExp.getAlias()!=null){
columnName = columnExp.getAlias();
}
else{
columnName = columnExp.getColumnName();
}
columnTemplateList.add(new Column(columnName,
columnExp.getType()));
}
} finally { } finally {
session.removeLocalTempTable(recursiveTable); session.removeLocalTempTable(recursiveTable);
} }
TableView view = createTemporarySessionView(tempViewName, querySQLOutput[0], columnTemplateList,true/*allowRecursiveQueryDetection*/, true);
return view;
}
/**
* Creates a list of column templates from a query (usually from WITH query, but could be any query)
* @param cols - an optional list of column names (can be specified by WITH clause overriding usual select names)
* @param theQuery - the query object we want the column list for
* @param querySQLOutput - array of length 1 to receive extra 'output' field in addition to return value
* - containing the SQL query of the Query object
* @return a list of column object returned by withQuery
*/
private List<Column> createQueryColumnTemplateList(String[] cols, Query theQuery, String[] querySQLOutput) {
List<Column> columnTemplateList = new ArrayList<Column>();
theQuery.prepare();
// array of length 1 to receive extra 'output' field in addition to return value
querySQLOutput[0] = StringUtils.cache(theQuery.getPlanSQL());
ArrayList<Expression> withExpressions = theQuery.getExpressions();
for (int i = 0; i < withExpressions.size(); ++i) {
Expression columnExp = withExpressions.get(i);
// use the passed in column name if supplied, otherwise use alias (if found) otherwise use column name
// derived from column expression
String columnName;
if (cols != null){
columnName = cols[i];
} else if (columnExp.getAlias()!=null){
columnName = columnExp.getAlias();
}
else{
columnName = columnExp.getColumnName();
}
columnTemplateList.add(new Column(columnName,
columnExp.getType()));
}
return columnTemplateList;
}
private TableView createTemporarySessionView(String tempViewName, String querySQL,
List<Column> columnTemplateList, boolean allowRecursiveQueryDetection, boolean addViewToSession) {
Schema schema = getSchemaWithDefault();
int id = database.allocateObjectId(); int id = database.allocateObjectId();
// No easy way to determine if this is a recursive query up front, so we just compile // No easy way to determine if this is a recursive query up front, so we just compile
// it twice - once without the flag set, and if we didn't see a recursive term, // it twice - once without the flag set, and if we didn't see a recursive term,
// then we just compile it again. // then we just compile it again.
TableView view = new TableView(schema, id, tempViewName, querySQL, TableView view = new TableView(schema, id, tempViewName, querySQL,
parameters, columnTemplateList.toArray(new Column[0]), session, parameters, columnTemplateList.toArray(new Column[0]), session,
true/* recursive */, false); allowRecursiveQueryDetection, false);
if (!view.isRecursiveQueryDetected()) { if (!view.isRecursiveQueryDetected() && allowRecursiveQueryDetection) {
view = new TableView(schema, id, tempViewName, querySQL, parameters, view = new TableView(schema, id, tempViewName, querySQL, parameters,
columnTemplateList.toArray(new Column[0]), session, columnTemplateList.toArray(new Column[0]), session,
false/* recursive */, false); false/* recursive */, false);
} }
view.setTableExpression(true); view.setTableExpression(true);
view.setTemporary(true); view.setTemporary(true);
session.addLocalTempTable(view); view.setHidden(true);
view.setOnCommitDrop(true); if(addViewToSession){
session.addLocalTempTable(view);
}
view.setOnCommitDrop(false);
return view; return view;
} }
......
...@@ -454,4 +454,8 @@ public abstract class Prepared { ...@@ -454,4 +454,8 @@ public abstract class Prepared {
public void setCteCleanups(List<TableView> cteCleanups) { public void setCteCleanups(List<TableView> cteCleanups) {
this.cteCleanups = cteCleanups; this.cteCleanups = cteCleanups;
} }
public Session getSession() {
return session;
}
} }
...@@ -30,30 +30,38 @@ import org.h2.value.ValueNull; ...@@ -30,30 +30,38 @@ import org.h2.value.ValueNull;
public class Delete extends Prepared { public class Delete extends Prepared {
private Expression condition; private Expression condition;
private TableFilter tableFilter; private TableFilter targetTableFilter;
/** /**
* The limit expression as specified in the LIMIT or TOP clause. * The limit expression as specified in the LIMIT or TOP clause.
*/ */
private Expression limitExpr; private Expression limitExpr;
/**
* This table filter is for MERGE..USING support - not used in stand-alone DML
*/
private TableFilter sourceTableFilter;
public Delete(Session session) { public Delete(Session session) {
super(session); super(session);
} }
public void setTableFilter(TableFilter tableFilter) { public void setTableFilter(TableFilter tableFilter) {
this.tableFilter = tableFilter; this.targetTableFilter = tableFilter;
} }
public void setCondition(Expression condition) { public void setCondition(Expression condition) {
this.condition = condition; this.condition = condition;
} }
public Expression getCondition( ) {
return this.condition;
}
@Override @Override
public int update() { public int update() {
tableFilter.startQuery(session); targetTableFilter.startQuery(session);
tableFilter.reset(); targetTableFilter.reset();
Table table = tableFilter.getTable(); Table table = targetTableFilter.getTable();
session.getUser().checkRight(table, Right.DELETE); session.getUser().checkRight(table, Right.DELETE);
table.fire(session, Trigger.DELETE, true); table.fire(session, Trigger.DELETE, true);
table.lock(session, true, false); table.lock(session, true, false);
...@@ -68,11 +76,11 @@ public class Delete extends Prepared { ...@@ -68,11 +76,11 @@ public class Delete extends Prepared {
try { try {
setCurrentRowNumber(0); setCurrentRowNumber(0);
int count = 0; int count = 0;
while (limitRows != 0 && tableFilter.next()) { while (limitRows != 0 && targetTableFilter.next()) {
setCurrentRowNumber(rows.size() + 1); setCurrentRowNumber(rows.size() + 1);
if (condition == null || Boolean.TRUE.equals( if (condition == null || Boolean.TRUE.equals(
condition.getBooleanValue(session))) { condition.getBooleanValue(session))) {
Row row = tableFilter.get(); Row row = targetTableFilter.get();
boolean done = false; boolean done = false;
if (table.fireRow()) { if (table.fireRow()) {
done = table.fireBeforeRow(session, row, null); done = table.fireBeforeRow(session, row, null);
...@@ -112,7 +120,7 @@ public class Delete extends Prepared { ...@@ -112,7 +120,7 @@ public class Delete extends Prepared {
public String getPlanSQL() { public String getPlanSQL() {
StringBuilder buff = new StringBuilder(); StringBuilder buff = new StringBuilder();
buff.append("DELETE "); buff.append("DELETE ");
buff.append("FROM ").append(tableFilter.getPlanSQL(false)); buff.append("FROM ").append(targetTableFilter.getPlanSQL(false));
if (condition != null) { if (condition != null) {
buff.append("\nWHERE ").append(StringUtils.unEnclose( buff.append("\nWHERE ").append(StringUtils.unEnclose(
condition.getSQL())); condition.getSQL()));
...@@ -127,15 +135,24 @@ public class Delete extends Prepared { ...@@ -127,15 +135,24 @@ public class Delete extends Prepared {
@Override @Override
public void prepare() { public void prepare() {
if (condition != null) { if (condition != null) {
condition.mapColumns(tableFilter, 0); condition.mapColumns(targetTableFilter, 0);
if(sourceTableFilter!=null){
condition.mapColumns(sourceTableFilter, 0);
}
condition = condition.optimize(session); condition = condition.optimize(session);
condition.createIndexConditions(session, tableFilter); condition.createIndexConditions(session, targetTableFilter);
}
TableFilter[] filters;
if(sourceTableFilter==null){
filters = new TableFilter[] { targetTableFilter };
}
else{
filters = new TableFilter[] { targetTableFilter, sourceTableFilter };
} }
TableFilter[] filters = new TableFilter[] { tableFilter }; PlanItem item = targetTableFilter.getBestPlanItem(session, filters, 0,
PlanItem item = tableFilter.getBestPlanItem(session, filters, 0,
ExpressionVisitor.allColumnsForTableFilters(filters)); ExpressionVisitor.allColumnsForTableFilters(filters));
tableFilter.setPlanItem(item); targetTableFilter.setPlanItem(item);
tableFilter.prepare(); targetTableFilter.prepare();
} }
@Override @Override
...@@ -162,4 +179,16 @@ public class Delete extends Prepared { ...@@ -162,4 +179,16 @@ public class Delete extends Prepared {
return true; return true;
} }
public void setSourceTableFilter(TableFilter sourceTableFilter) {
this.sourceTableFilter = sourceTableFilter;
}
public TableFilter getTableFilter() {
return targetTableFilter;
}
public TableFilter getSourceTableFilter() {
return sourceTableFilter;
}
} }
...@@ -28,6 +28,7 @@ import org.h2.result.ResultTarget; ...@@ -28,6 +28,7 @@ import org.h2.result.ResultTarget;
import org.h2.result.Row; import org.h2.result.Row;
import org.h2.table.Column; import org.h2.table.Column;
import org.h2.table.Table; import org.h2.table.Table;
import org.h2.table.TableFilter;
import org.h2.util.New; import org.h2.util.New;
import org.h2.util.StatementBuilder; import org.h2.util.StatementBuilder;
import org.h2.value.Value; import org.h2.value.Value;
...@@ -46,6 +47,10 @@ public class Insert extends Prepared implements ResultTarget { ...@@ -46,6 +47,10 @@ public class Insert extends Prepared implements ResultTarget {
private boolean sortedInsertMode; private boolean sortedInsertMode;
private int rowNumber; private int rowNumber;
private boolean insertFromSelect; private boolean insertFromSelect;
/**
* This table filter is for MERGE..USING support - not used in stand-alone DML
*/
private TableFilter sourceTableFilter;
/** /**
* For MySQL-style INSERT ... ON DUPLICATE KEY UPDATE .... * For MySQL-style INSERT ... ON DUPLICATE KEY UPDATE ....
...@@ -267,6 +272,9 @@ public class Insert extends Prepared implements ResultTarget { ...@@ -267,6 +272,9 @@ public class Insert extends Prepared implements ResultTarget {
for (int i = 0, len = expr.length; i < len; i++) { for (int i = 0, len = expr.length; i < len; i++) {
Expression e = expr[i]; Expression e = expr[i];
if (e != null) { if (e != null) {
if(sourceTableFilter!=null){
e.mapColumns(sourceTableFilter, 0);
}
e = e.optimize(session); e = e.optimize(session);
if (e instanceof Parameter) { if (e instanceof Parameter) {
Parameter p = (Parameter) e; Parameter p = (Parameter) e;
...@@ -395,4 +403,8 @@ public class Insert extends Prepared implements ResultTarget { ...@@ -395,4 +403,8 @@ public class Insert extends Prepared implements ResultTarget {
return condition; return condition;
} }
public void setSourceTableFilter(TableFilter sourceTableFilter) {
this.sourceTableFilter = sourceTableFilter;
}
} }
...@@ -6,7 +6,6 @@ ...@@ -6,7 +6,6 @@
package org.h2.command.dml; package org.h2.command.dml;
import java.util.ArrayList; import java.util.ArrayList;
import org.h2.api.ErrorCode; import org.h2.api.ErrorCode;
import org.h2.api.Trigger; import org.h2.api.Trigger;
import org.h2.command.Command; import org.h2.command.Command;
...@@ -23,6 +22,7 @@ import org.h2.result.ResultInterface; ...@@ -23,6 +22,7 @@ import org.h2.result.ResultInterface;
import org.h2.result.Row; import org.h2.result.Row;
import org.h2.table.Column; import org.h2.table.Column;
import org.h2.table.Table; import org.h2.table.Table;
import org.h2.table.TableFilter;
import org.h2.util.New; import org.h2.util.New;
import org.h2.util.StatementBuilder; import org.h2.util.StatementBuilder;
import org.h2.value.Value; import org.h2.value.Value;
...@@ -33,10 +33,11 @@ import org.h2.value.Value; ...@@ -33,10 +33,11 @@ import org.h2.value.Value;
*/ */
public class Merge extends Prepared { public class Merge extends Prepared {
private Table table; private Table targetTable;
private TableFilter targetTableFilter;
private Column[] columns; private Column[] columns;
private Column[] keys; private Column[] keys;
private final ArrayList<Expression[]> list = New.arrayList(); private final ArrayList<Expression[]> valuesExpressionList = New.arrayList();
private Query query; private Query query;
private Prepared update; private Prepared update;
...@@ -52,8 +53,8 @@ public class Merge extends Prepared { ...@@ -52,8 +53,8 @@ public class Merge extends Prepared {
} }
} }
public void setTable(Table table) { public void setTargetTable(Table targetTable) {
this.table = table; this.targetTable = targetTable;
} }
public void setColumns(Column[] columns) { public void setColumns(Column[] columns) {
...@@ -67,28 +68,29 @@ public class Merge extends Prepared { ...@@ -67,28 +68,29 @@ public class Merge extends Prepared {
public void setQuery(Query query) { public void setQuery(Query query) {
this.query = query; this.query = query;
} }
/** /**
* Add a row to this merge statement. * Add a row to this merge statement.
* *
* @param expr the list of values * @param expr the list of values
*/ */
public void addRow(Expression[] expr) { public void addRow(Expression[] expr) {
list.add(expr); valuesExpressionList.add(expr);
} }
@Override @Override
public int update() { public int update() {
int count; int count;
session.getUser().checkRight(table, Right.INSERT); session.getUser().checkRight(targetTable, Right.INSERT);
session.getUser().checkRight(table, Right.UPDATE); session.getUser().checkRight(targetTable, Right.UPDATE);
setCurrentRowNumber(0); setCurrentRowNumber(0);
if (list.size() > 0) { if (valuesExpressionList.size() > 0) {
// process values in list
count = 0; count = 0;
for (int x = 0, size = list.size(); x < size; x++) { for (int x = 0, size = valuesExpressionList.size(); x < size; x++) {
setCurrentRowNumber(x + 1); setCurrentRowNumber(x + 1);
Expression[] expr = list.get(x); Expression[] expr = valuesExpressionList.get(x);
Row newRow = table.getTemplateRow(); Row newRow = targetTable.getTemplateRow();
for (int i = 0, len = columns.length; i < len; i++) { for (int i = 0, len = columns.length; i < len; i++) {
Column c = columns[i]; Column c = columns[i];
int index = c.getColumnId(); int index = c.getColumnId();
...@@ -107,14 +109,15 @@ public class Merge extends Prepared { ...@@ -107,14 +109,15 @@ public class Merge extends Prepared {
count++; count++;
} }
} else { } else {
// process select data for list
ResultInterface rows = query.query(0); ResultInterface rows = query.query(0);
count = 0; count = 0;
table.fire(session, Trigger.UPDATE | Trigger.INSERT, true); targetTable.fire(session, Trigger.UPDATE | Trigger.INSERT, true);
table.lock(session, true, false); targetTable.lock(session, true, false);
while (rows.next()) { while (rows.next()) {
count++; count++;
Value[] r = rows.currentRow(); Value[] r = rows.currentRow();
Row newRow = table.getTemplateRow(); Row newRow = targetTable.getTemplateRow();
setCurrentRowNumber(count); setCurrentRowNumber(count);
for (int j = 0; j < columns.length; j++) { for (int j = 0; j < columns.length; j++) {
Column c = columns[j]; Column c = columns[j];
...@@ -129,12 +132,12 @@ public class Merge extends Prepared { ...@@ -129,12 +132,12 @@ public class Merge extends Prepared {
merge(newRow); merge(newRow);
} }
rows.close(); rows.close();
table.fire(session, Trigger.UPDATE | Trigger.INSERT, false); targetTable.fire(session, Trigger.UPDATE | Trigger.INSERT, false);
} }
return count; return count;
} }
private void merge(Row row) { protected void merge(Row row) {
ArrayList<Parameter> k = update.getParameters(); ArrayList<Parameter> k = update.getParameters();
for (int i = 0; i < columns.length; i++) { for (int i = 0; i < columns.length; i++) {
Column col = columns[i]; Column col = columns[i];
...@@ -151,16 +154,20 @@ public class Merge extends Prepared { ...@@ -151,16 +154,20 @@ public class Merge extends Prepared {
Parameter p = k.get(columns.length + i); Parameter p = k.get(columns.length + i);
p.setValue(v); p.setValue(v);
} }
// try and update
int count = update.update(); int count = update.update();
// if update fails try an insert
if (count == 0) { if (count == 0) {
try { try {
table.validateConvertUpdateSequence(session, row); targetTable.validateConvertUpdateSequence(session, row);
boolean done = table.fireBeforeRow(session, null, row); boolean done = targetTable.fireBeforeRow(session, null, row);
if (!done) { if (!done) {
table.lock(session, true, false); targetTable.lock(session, true, false);
table.addRow(session, row); targetTable.addRow(session, row);
session.log(table, UndoLogRecord.INSERT, row); session.log(targetTable, UndoLogRecord.INSERT, row);
table.fireAfterRow(session, null, row, false); targetTable.fireAfterRow(session, null, row, false);
} }
} catch (DbException e) { } catch (DbException e) {
if (e.getErrorCode() == ErrorCode.DUPLICATE_KEY_1) { if (e.getErrorCode() == ErrorCode.DUPLICATE_KEY_1) {
...@@ -179,21 +186,21 @@ public class Merge extends Prepared { ...@@ -179,21 +186,21 @@ public class Merge extends Prepared {
} }
} }
if (indexMatchesKeys) { if (indexMatchesKeys) {
throw DbException.get(ErrorCode.CONCURRENT_UPDATE_1, table.getName()); throw DbException.get(ErrorCode.CONCURRENT_UPDATE_1, targetTable.getName());
} }
} }
} }
throw e; throw e;
} }
} else if (count != 1) { } else if (count != 1) {
throw DbException.get(ErrorCode.DUPLICATE_KEY_1, table.getSQL()); throw DbException.get(ErrorCode.DUPLICATE_KEY_1, targetTable.getSQL());
} }
} }
@Override @Override
public String getPlanSQL() { public String getPlanSQL() {
StatementBuilder buff = new StatementBuilder("MERGE INTO "); StatementBuilder buff = new StatementBuilder("MERGE INTO ");
buff.append(table.getSQL()).append('('); buff.append(targetTable.getSQL()).append('(');
for (Column c : columns) { for (Column c : columns) {
buff.appendExceptFirst(", "); buff.appendExceptFirst(", ");
buff.append(c.getSQL()); buff.append(c.getSQL());
...@@ -209,10 +216,10 @@ public class Merge extends Prepared { ...@@ -209,10 +216,10 @@ public class Merge extends Prepared {
buff.append(')'); buff.append(')');
} }
buff.append('\n'); buff.append('\n');
if (list.size() > 0) { if (valuesExpressionList.size() > 0) {
buff.append("VALUES "); buff.append("VALUES ");
int row = 0; int row = 0;
for (Expression[] expr : list) { for (Expression[] expr : valuesExpressionList) {
if (row++ > 0) { if (row++ > 0) {
buff.append(", "); buff.append(", ");
} }
...@@ -237,15 +244,15 @@ public class Merge extends Prepared { ...@@ -237,15 +244,15 @@ public class Merge extends Prepared {
@Override @Override
public void prepare() { public void prepare() {
if (columns == null) { if (columns == null) {
if (list.size() > 0 && list.get(0).length == 0) { if (valuesExpressionList.size() > 0 && valuesExpressionList.get(0).length == 0) {
// special case where table is used as a sequence // special case where table is used as a sequence
columns = new Column[0]; columns = new Column[0];
} else { } else {
columns = table.getColumns(); columns = targetTable.getColumns();
} }
} }
if (list.size() > 0) { if (valuesExpressionList.size() > 0) {
for (Expression[] expr : list) { for (Expression[] expr : valuesExpressionList) {
if (expr.length != columns.length) { if (expr.length != columns.length) {
throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH); throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
} }
...@@ -263,14 +270,14 @@ public class Merge extends Prepared { ...@@ -263,14 +270,14 @@ public class Merge extends Prepared {
} }
} }
if (keys == null) { if (keys == null) {
Index idx = table.getPrimaryKey(); Index idx = targetTable.getPrimaryKey();
if (idx == null) { if (idx == null) {
throw DbException.get(ErrorCode.CONSTRAINT_NOT_FOUND_1, "PRIMARY KEY"); throw DbException.get(ErrorCode.CONSTRAINT_NOT_FOUND_1, "PRIMARY KEY");
} }
keys = idx.getColumns(); keys = idx.getColumns();
} }
StatementBuilder buff = new StatementBuilder("UPDATE "); StatementBuilder buff = new StatementBuilder("UPDATE ");
buff.append(table.getSQL()).append(" SET "); buff.append(targetTable.getSQL()).append(" SET ");
for (Column c : columns) { for (Column c : columns) {
buff.appendExceptFirst(", "); buff.appendExceptFirst(", ");
buff.append(c.getSQL()).append("=?"); buff.append(c.getSQL()).append("=?");
...@@ -305,4 +312,19 @@ public class Merge extends Prepared { ...@@ -305,4 +312,19 @@ public class Merge extends Prepared {
return true; return true;
} }
public Table getTargetTable() {
return targetTable;
}
public TableFilter getTargetTableFilter() {
return targetTableFilter;
}
public void setTargetTableFilter(TableFilter targetTableFilter) {
this.targetTableFilter = targetTableFilter;
setTargetTable(targetTableFilter.getTable());
}
} }
/*
* Copyright 2004-2017 H2 Group. Multiple-Licensed under the MPL 2.0,
* and the EPL 1.0 (http://h2database.com/html/license.html).
* Initial Developer: H2 Group
*/
package org.h2.command.dml;
import java.util.ArrayList;
import java.util.Arrays;
import java.util.HashMap;
import java.util.HashSet;
import org.h2.api.ErrorCode;
import org.h2.api.Trigger;
import org.h2.command.CommandInterface;
import org.h2.command.Prepared;
import org.h2.engine.Right;
import org.h2.engine.Session;
import org.h2.expression.ConditionAndOr;
import org.h2.expression.Expression;
import org.h2.expression.ExpressionVisitor;
import org.h2.message.DbException;
import org.h2.result.ResultInterface;
import org.h2.result.Row;
import org.h2.result.RowImpl;
import org.h2.table.Column;
import org.h2.table.Table;
import org.h2.table.TableFilter;
import org.h2.util.New;
import org.h2.util.StatementBuilder;
import org.h2.value.Value;
/**
* This class represents the statement syntax
* MERGE table alias USING...
*
* It does not replace the existing MERGE INTO... KEYS... form.
*
* It supports the SQL 2003/2008 standard MERGE statement:
* http://en.wikipedia.org/wiki/Merge_%28SQL%29
*
* Database management systems Oracle Database, DB2, Teradata, EXASOL, Firebird, CUBRID, HSQLDB,
* MS SQL, Vectorwise and Apache Derby & Postgres support the standard syntax of the
* SQL 2003/2008 MERGE command:
*
* MERGE INTO targetTable AS T USING sourceTable AS S ON (T.ID = S.ID)
* WHEN MATCHED THEN
* UPDATE SET column1 = value1 [, column2 = value2 ...] WHERE column1=valueUpdate
* DELETE WHERE column1=valueDelete
* WHEN NOT MATCHED THEN
* INSERT (column1 [, column2 ...]) VALUES (value1 [, value2 ...]);
*
* Only Oracle support the additional optional DELETE clause.
*
* Implementation notes:
*
* 1) The ON clause must specify 1 or more columns from the TARGET table because they are
* used in the plan SQL WHERE statement. Otherwise an exception is raised.
*
* 2) The ON clause must specify 1 or more columns from the SOURCE table/query because they
* are used to track the join key values for every source table row - to prevent any
* TARGET rows from being updated twice per MERGE USING statement.
*
* This is to implement a requirement from the MERGE INTO specification
* requiring each row from being updated more than once per MERGE USING statement.
* The source columns are used to gather the effective "key" values which have been
* updated, in order to implement this requirement.
* If the no SOURCE table/query columns are found in the ON clause, then an exception is
* raised.
*
* The update row counts of the embedded UPDATE and DELETE statements are also tracked to
* ensure no more than 1 row is ever updated. (Note One special case of this is that
* the DELETE is allowed to affect the same row which was updated by UPDATE - this is an
* Oracle only extension.)
*
* 3) UPDATE and DELETE statements are allowed to specify extra conditional criteria
* (in the WHERE clause) to allow fine-grained control of actions when a record is found.
* The ON clause conditions are always prepended to the WHERE clause of these embedded
* statements, so they will never update more than the ON join condition.
*
* 4) Previously if neither UPDATE or DELETE clause is supplied, but INSERT is supplied - the INSERT
* action is always triggered. This is because the embedded UPDATE and DELETE statement's
* returned update row count is used to detect a matching join.
* If neither of the two the statements are provided, no matching join is EVER detected.
* A fix for this is now implemented as described below:
* We now generate a "matchSelect" query and use that to always detect
* a match join - rather than relying on UPDATE or DELETE statements.
*
* This is an improvement, especially in the case that if either of the
* UPDATE or DELETE statements had their own fine-grained WHERE conditions, making
* them completely different conditions than the plain ON condition clause which
* the SQL author would be specifying/expecting.
*
* An additional benefit of this solution is that this "matchSelect" query
* is used to return the ROWID of the found (or inserted) query - for more accurate
* enforcing of the only-update-each-target-row-once rule.
*/
public class MergeUsing extends Prepared {
// Merge fields
private Table targetTable;
private TableFilter targetTableFilter;
private Column[] columns;
private Column[] keys;
private final ArrayList<Expression[]> valuesExpressionList = New.arrayList();
private Query query;
// MergeUsing fields
private TableFilter sourceTableFilter;
private Expression onCondition;
private Update updateCommand;
private Delete deleteCommand;
private Insert insertCommand;
private String queryAlias;
private int countUpdatedRows=0;
private Column[] sourceKeys;
private Select targetMatchQuery;
private HashMap<Value, Integer> targetRowidsRemembered = new HashMap<Value,Integer>();
private int sourceQueryRowNumber= 0;
public MergeUsing(Merge merge) {
super(merge.getSession());
// bring across only the already parsed data from Merge...
this.targetTable = merge.getTargetTable();
this.targetTableFilter = merge.getTargetTableFilter();
}
@Override
public int update() {
// clear list of source table keys & rowids we have processed already
targetRowidsRemembered.clear();
if(targetTableFilter!=null){
targetTableFilter.startQuery(session);
targetTableFilter.reset();
}
if(sourceTableFilter!=null){
sourceTableFilter.startQuery(session);
sourceTableFilter.reset();
}
sourceQueryRowNumber = 0;
checkRights();
setCurrentRowNumber(0);
// process source select query data for row creation
ResultInterface rows = query.query(0);
targetTable.fire(session, evaluateTriggerMasks(), true);
targetTable.lock(session, true, false);
while (rows.next()) {
sourceQueryRowNumber++;
Value[] sourceRowValues = rows.currentRow();
Row sourceRow = new RowImpl(sourceRowValues,0);
setCurrentRowNumber(sourceQueryRowNumber);
merge(sourceRow, sourceRowValues);
}
rows.close();
targetTable.fire(session, evaluateTriggerMasks(), false);
return countUpdatedRows;
}
private int evaluateTriggerMasks() {
int masks = 0;
if(insertCommand!=null){
masks |= Trigger.INSERT;
}
if(updateCommand!=null){
masks |= Trigger.UPDATE;
}
if(deleteCommand!=null){
masks |= Trigger.DELETE;
}
return masks;
}
private void checkRights() {
if(insertCommand!=null){
session.getUser().checkRight(targetTable, Right.INSERT);
}
if(updateCommand!=null){
session.getUser().checkRight(targetTable, Right.UPDATE);
}
if(deleteCommand!=null){
session.getUser().checkRight(targetTable, Right.DELETE);
}
// check the underlying tables
session.getUser().checkRight(targetTable, Right.SELECT);
session.getUser().checkRight(sourceTableFilter.getTable(), Right.SELECT);
}
protected void merge(Row sourceRow, Value[] sourceRowValues) {
// put the column values into the table filter
sourceTableFilter.set(sourceRow);
// Is the target row there already ?
boolean rowFound = isTargetRowFound();
// try and perform an update
int rowUpdateCount = 0;
if(rowFound){
if(updateCommand!=null){
rowUpdateCount += updateCommand.update();
}
if(deleteCommand!=null){
int deleteRowUpdateCount = deleteCommand.update();
// under oracle rules these updates & delete combinations are allowed together
if(rowUpdateCount==1 && deleteRowUpdateCount==1){
countUpdatedRows+=deleteRowUpdateCount;
deleteRowUpdateCount=0;
}
else{
rowUpdateCount += deleteRowUpdateCount;
}
}
}
else
{
// if either updates do nothing, try an insert
if (rowUpdateCount == 0) {
rowUpdateCount += addRowByCommandInsert(session,sourceRow);
} else if (rowUpdateCount != 1) {
throw DbException.get(ErrorCode.DUPLICATE_KEY_1, "Duplicate key inserted "+rowUpdateCount+" rows at once, only 1 expected:"+targetTable.getSQL());
}
}
countUpdatedRows+=rowUpdateCount;
}
private boolean isTargetRowFound(){
ResultInterface rows = targetMatchQuery.query(0);
int countTargetRowsFound = 0;
Value[] targetRowIdValue=null;
while (rows.next()) {
countTargetRowsFound++;
targetRowIdValue = rows.currentRow();
// throw and exception if we have processed this _ROWID_ before...
if(targetRowidsRemembered.containsKey(targetRowIdValue[0])){
throw DbException.get(ErrorCode.DUPLICATE_KEY_1, "Merge using ON column expression, duplicate _ROWID_ target record already updated, deleted or inserted:_ROWID_="
+targetRowIdValue[0].toString()
+":in:"+targetTableFilter.getTable()
+":conflicting source row number:"+targetRowidsRemembered.get(targetRowIdValue[0]));
}else{
// remember the source column values we have used before (they are the effective ON clause keys
// and should not be repeated
targetRowidsRemembered.put(targetRowIdValue[0],sourceQueryRowNumber);
}
}
rows.close();
if(countTargetRowsFound>1){
throw DbException.get(ErrorCode.DUPLICATE_KEY_1, "Duplicate key updated "+countTargetRowsFound+" rows at once, only 1 expected:_ROWID_="
+targetRowIdValue[0].toString()
+":in:"+targetTableFilter.getTable()
+":conflicting source row number:"+targetRowidsRemembered.get(targetRowIdValue[0]));
}
return countTargetRowsFound>0;
}
private int addRowByCommandInsert(Session session, Row sourceRow) {
int localCount = 0;
if(insertCommand!=null){
localCount += insertCommand.update();
if(!isTargetRowFound()){
throw DbException.get(ErrorCode.GENERAL_ERROR_1, "Expected to find key after row inserted, but none found. Insert does not match ON condition.:"+targetTable.getSQL()+":source row="+Arrays.asList(sourceRow.getValueList()));
}
}
return localCount;
}
// Use the regular merge syntax as our plan SQL
@Override
public String getPlanSQL() {
StatementBuilder buff = new StatementBuilder("MERGE INTO ");
buff.append(targetTable.getSQL()).append('(');
for (Column c : columns) {
buff.appendExceptFirst(", ");
buff.append(c.getSQL());
}
buff.append(')');
if (keys != null) {
buff.append(" KEY(");
buff.resetCount();
for (Column c : keys) {
buff.appendExceptFirst(", ");
buff.append(c.getSQL());
}
buff.append(')');
}
buff.append('\n');
if (valuesExpressionList.size() > 0) {
buff.append("VALUES ");
int row = 0;
for (Expression[] expr : valuesExpressionList) {
if (row++ > 0) {
buff.append(", ");
}
buff.append('(');
buff.resetCount();
for (Expression e : expr) {
buff.appendExceptFirst(", ");
if (e == null) {
buff.append("DEFAULT");
} else {
buff.append(e.getSQL());
}
}
buff.append(')');
}
} else {
buff.append(query.getPlanSQL());
}
return buff.toString();
}
@Override
public void prepare() {
onCondition.addFilterConditions(sourceTableFilter, true);
onCondition.addFilterConditions(targetTableFilter, true);
onCondition.mapColumns(sourceTableFilter, 2);
onCondition.mapColumns(targetTableFilter, 1);
if (keys == null) {
HashSet<Column> targetColumns = buildColumnListFromOnCondition(targetTableFilter);
keys = targetColumns.toArray(new Column[0]);
}
if(keys.length==0){
throw DbException.get(ErrorCode.COLUMN_NOT_FOUND_1,
"No references to target columns found in ON clause:"+targetTableFilter.toString());
}
if (sourceKeys == null) {
HashSet<Column> sourceColumns = buildColumnListFromOnCondition(sourceTableFilter);
sourceKeys = sourceColumns.toArray(new Column[0]);
}
if(sourceKeys.length==0){
throw DbException.get(ErrorCode.COLUMN_NOT_FOUND_1,
"No references to source columns found in ON clause:"+sourceTableFilter.toString());
}
// only do the optimize now - before we have already gathered the unoptimized column data
onCondition = onCondition.optimize(session);
onCondition.createIndexConditions(session, sourceTableFilter);
onCondition.createIndexConditions(session, targetTableFilter);
if (columns == null) {
if (valuesExpressionList.size() > 0 && valuesExpressionList.get(0).length == 0) {
// special case where table is used as a sequence
columns = new Column[0];
} else {
columns = targetTable.getColumns();
}
}
if (valuesExpressionList.size() > 0) {
for (Expression[] expr : valuesExpressionList) {
if (expr.length != columns.length) {
throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
}
for (int i = 0; i < expr.length; i++) {
Expression e = expr[i];
if (e != null) {
expr[i] = e.optimize(session);
}
}
}
} else {
query.prepare();
if (query.getColumnCount() != columns.length) {
throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
}
}
int embeddedStatementsCount = 0;
// Prepare each of the sub-commands ready to aid in the MERGE collaboration
if(updateCommand!=null){
updateCommand.setSourceTableFilter(sourceTableFilter);
updateCommand.setCondition(appendOnCondition(updateCommand));
updateCommand.prepare();
embeddedStatementsCount++;
}
if(deleteCommand!=null){
deleteCommand.setSourceTableFilter(sourceTableFilter);
deleteCommand.setCondition(appendOnCondition(deleteCommand));
deleteCommand.prepare();
embeddedStatementsCount++;
}
if(insertCommand!=null){
insertCommand.setSourceTableFilter(sourceTableFilter);
insertCommand.prepare();
embeddedStatementsCount++;
}
if(embeddedStatementsCount==0){
throw DbException.get(ErrorCode.SYNTAX_ERROR_1,
"At least UPDATE, DELETE or INSERT embedded statement must be supplied.");
}
// setup the targetMatchQuery - for detecting if the target row exists
Expression targetMatchCondition = targetMatchQuery.getCondition();
targetMatchCondition.addFilterConditions(sourceTableFilter, true);
targetMatchCondition.mapColumns(sourceTableFilter, 2);
targetMatchCondition = targetMatchCondition.optimize(session);
targetMatchCondition.createIndexConditions(session, sourceTableFilter);
targetMatchQuery.prepare();
}
private HashSet<Column> buildColumnListFromOnCondition(TableFilter anyTableFilter) {
HashSet<Column> filteredColumns = new HashSet<Column>();
HashSet<Column> columns = new HashSet<Column>();
ExpressionVisitor visitor = ExpressionVisitor.getColumnsVisitor(columns);
onCondition.isEverything(visitor);
for(Column c: columns){
if(c!=null && c.getTable()==anyTableFilter.getTable()){
filteredColumns.add(c);
}
}
return filteredColumns;
}
private Expression appendOnCondition(Update updateCommand) {
if (updateCommand.getCondition()==null){
return onCondition;
}
return new ConditionAndOr(ConditionAndOr.AND,updateCommand.getCondition(),onCondition);
}
private Expression appendOnCondition(Delete deleteCommand) {
if (deleteCommand.getCondition()==null){
return onCondition;
}
return new ConditionAndOr(ConditionAndOr.AND,deleteCommand.getCondition(),onCondition);
}
public void setSourceTableFilter(TableFilter sourceTableFilter) {
this.sourceTableFilter = sourceTableFilter;
}
public TableFilter getSourceTableFilter() {
return sourceTableFilter;
}
public void setOnCondition(Expression condition) {
this.onCondition = condition;
}
public Expression getOnCondition() {
return onCondition;
}
public Prepared getUpdateCommand() {
return updateCommand;
}
public void setUpdateCommand(Update updateCommand) {
this.updateCommand = updateCommand;
}
public Prepared getDeleteCommand() {
return deleteCommand;
}
public void setDeleteCommand(Delete deleteCommand) {
this.deleteCommand = deleteCommand;
}
public Insert getInsertCommand() {
return insertCommand;
}
public void setInsertCommand(Insert insertCommand) {
this.insertCommand = insertCommand;
}
public void setQueryAlias(String alias) {
this.queryAlias = alias;
}
public String getQueryAlias() {
return this.queryAlias;
}
public Query getQuery() {
return query;
}
public void setQuery(Query query) {
this.query = query;
}
public void setTargetTableFilter(TableFilter targetTableFilter) {
this.targetTableFilter = targetTableFilter;
}
public TableFilter getTargetTableFilter() {
return targetTableFilter;
}
public Table getTargetTable() {
return targetTable;
}
public void setTargetTable(Table targetTable) {
this.targetTable = targetTable;
}
public Select getTargetMatchQuery() {
return targetMatchQuery;
}
public void setTargetMatchQuery(Select targetMatchQuery) {
this.targetMatchQuery = targetMatchQuery;
}
// Prepared interface implementations
@Override
public boolean isTransactional() {
return true;
}
@Override
public ResultInterface queryMeta() {
return null;
}
@Override
public int getType() {
return CommandInterface.MERGE;
}
}
...@@ -168,6 +168,10 @@ public class Select extends Query { ...@@ -168,6 +168,10 @@ public class Select extends Query {
} }
} }
public Expression getCondition() {
return condition;
}
private LazyResult queryGroupSorted(int columnCount, ResultTarget result) { private LazyResult queryGroupSorted(int columnCount, ResultTarget result) {
LazyResultGroupSorted lazyResult = new LazyResultGroupSorted(expressionArray, columnCount); LazyResultGroupSorted lazyResult = new LazyResultGroupSorted(expressionArray, columnCount);
if (result == null) { if (result == null) {
......
...@@ -38,7 +38,11 @@ import org.h2.value.ValueNull; ...@@ -38,7 +38,11 @@ import org.h2.value.ValueNull;
public class Update extends Prepared { public class Update extends Prepared {
private Expression condition; private Expression condition;
private TableFilter tableFilter; private TableFilter targetTableFilter;// target of update
/**
* This table filter is for MERGE..USING support - not used in stand-alone DML
*/
private TableFilter sourceTableFilter;
/** The limit expression as specified in the LIMIT clause. */ /** The limit expression as specified in the LIMIT clause. */
private Expression limitExpr; private Expression limitExpr;
...@@ -51,12 +55,16 @@ public class Update extends Prepared { ...@@ -51,12 +55,16 @@ public class Update extends Prepared {
} }
public void setTableFilter(TableFilter tableFilter) { public void setTableFilter(TableFilter tableFilter) {
this.tableFilter = tableFilter; this.targetTableFilter = tableFilter;
} }
public void setCondition(Expression condition) { public void setCondition(Expression condition) {
this.condition = condition; this.condition = condition;
} }
public Expression getCondition( ) {
return this.condition;
}
/** /**
* Add an assignment of the form column = expression. * Add an assignment of the form column = expression.
...@@ -79,11 +87,11 @@ public class Update extends Prepared { ...@@ -79,11 +87,11 @@ public class Update extends Prepared {
@Override @Override
public int update() { public int update() {
tableFilter.startQuery(session); targetTableFilter.startQuery(session);
tableFilter.reset(); targetTableFilter.reset();
RowList rows = new RowList(session); RowList rows = new RowList(session);
try { try {
Table table = tableFilter.getTable(); Table table = targetTableFilter.getTable();
session.getUser().checkRight(table, Right.UPDATE); session.getUser().checkRight(table, Right.UPDATE);
table.fire(session, Trigger.UPDATE, true); table.fire(session, Trigger.UPDATE, true);
table.lock(session, true, false); table.lock(session, true, false);
...@@ -99,14 +107,14 @@ public class Update extends Prepared { ...@@ -99,14 +107,14 @@ public class Update extends Prepared {
limitRows = v.getInt(); limitRows = v.getInt();
} }
} }
while (tableFilter.next()) { while (targetTableFilter.next()) {
setCurrentRowNumber(count+1); setCurrentRowNumber(count+1);
if (limitRows >= 0 && count >= limitRows) { if (limitRows >= 0 && count >= limitRows) {
break; break;
} }
if (condition == null || if (condition == null ||
Boolean.TRUE.equals(condition.getBooleanValue(session))) { Boolean.TRUE.equals(condition.getBooleanValue(session))) {
Row oldRow = tableFilter.get(); Row oldRow = targetTableFilter.get();
Row newRow = table.getTemplateRow(); Row newRow = table.getTemplateRow();
for (int i = 0; i < columnCount; i++) { for (int i = 0; i < columnCount; i++) {
Expression newExpr = expressionMap.get(columns[i]); Expression newExpr = expressionMap.get(columns[i]);
...@@ -161,7 +169,7 @@ public class Update extends Prepared { ...@@ -161,7 +169,7 @@ public class Update extends Prepared {
@Override @Override
public String getPlanSQL() { public String getPlanSQL() {
StatementBuilder buff = new StatementBuilder("UPDATE "); StatementBuilder buff = new StatementBuilder("UPDATE ");
buff.append(tableFilter.getPlanSQL(false)).append("\nSET\n "); buff.append(targetTableFilter.getPlanSQL(false)).append("\nSET\n ");
for (int i = 0, size = columns.size(); i < size; i++) { for (int i = 0, size = columns.size(); i < size; i++) {
Column c = columns.get(i); Column c = columns.get(i);
Expression e = expressionMap.get(c); Expression e = expressionMap.get(c);
...@@ -181,21 +189,30 @@ public class Update extends Prepared { ...@@ -181,21 +189,30 @@ public class Update extends Prepared {
@Override @Override
public void prepare() { public void prepare() {
if (condition != null) { if (condition != null) {
condition.mapColumns(tableFilter, 0); condition.mapColumns(targetTableFilter, 0);
condition = condition.optimize(session); condition = condition.optimize(session);
condition.createIndexConditions(session, tableFilter); condition.createIndexConditions(session, targetTableFilter);
} }
for (int i = 0, size = columns.size(); i < size; i++) { for (int i = 0, size = columns.size(); i < size; i++) {
Column c = columns.get(i); Column c = columns.get(i);
Expression e = expressionMap.get(c); Expression e = expressionMap.get(c);
e.mapColumns(tableFilter, 0); e.mapColumns(targetTableFilter, 0);
if (sourceTableFilter!=null){
e.mapColumns(sourceTableFilter, 0);
}
expressionMap.put(c, e.optimize(session)); expressionMap.put(c, e.optimize(session));
} }
TableFilter[] filters = new TableFilter[] { tableFilter }; TableFilter[] filters;
PlanItem item = tableFilter.getBestPlanItem(session, filters, 0, if(sourceTableFilter==null){
filters = new TableFilter[] { targetTableFilter };
}
else{
filters = new TableFilter[] { targetTableFilter, sourceTableFilter };
}
PlanItem item = targetTableFilter.getBestPlanItem(session, filters, 0,
ExpressionVisitor.allColumnsForTableFilters(filters)); ExpressionVisitor.allColumnsForTableFilters(filters));
tableFilter.setPlanItem(item); targetTableFilter.setPlanItem(item);
tableFilter.prepare(); targetTableFilter.prepare();
} }
@Override @Override
...@@ -222,4 +239,11 @@ public class Update extends Prepared { ...@@ -222,4 +239,11 @@ public class Update extends Prepared {
return true; return true;
} }
public TableFilter getSourceTableFilter() {
return sourceTableFilter;
}
public void setSourceTableFilter(TableFilter sourceTableFilter) {
this.sourceTableFilter = sourceTableFilter;
}
} }
...@@ -361,7 +361,7 @@ public class Session extends SessionWithState { ...@@ -361,7 +361,7 @@ public class Session extends SessionWithState {
} }
if (localTempTables.get(table.getName()) != null) { if (localTempTables.get(table.getName()) != null) {
throw DbException.get(ErrorCode.TABLE_OR_VIEW_ALREADY_EXISTS_1, throw DbException.get(ErrorCode.TABLE_OR_VIEW_ALREADY_EXISTS_1,
table.getSQL()); table.getSQL()+" AS "+table.getName());
} }
modificationId++; modificationId++;
localTempTables.put(table.getName(), table); localTempTables.put(table.getName(), table);
......
...@@ -103,7 +103,8 @@ public class JdbcConnection extends TraceObject implements Connection, ...@@ -103,7 +103,8 @@ public class JdbcConnection extends TraceObject implements Connection,
/** /**
* INTERNAL * INTERNAL
*/ */
public JdbcConnection(ConnectionInfo ci, boolean useBaseDir) @SuppressWarnings("resource")// the session closable object does not leak as Eclipse warns - due to the CloseWatcher
public JdbcConnection(ConnectionInfo ci, boolean useBaseDir)
throws SQLException { throws SQLException {
try { try {
if (useBaseDir) { if (useBaseDir) {
......
...@@ -567,8 +567,6 @@ public class TableFilter implements ColumnResolver { ...@@ -567,8 +567,6 @@ public class TableFilter implements ColumnResolver {
private void checkTimeout() { private void checkTimeout() {
session.checkCanceled(); session.checkCanceled();
// System.out.println(this.alias+ " " + table.getName() + ": " +
// scanCount);
} }
/** /**
......
...@@ -45,6 +45,7 @@ import org.h2.test.db.TestLinkedTable; ...@@ -45,6 +45,7 @@ import org.h2.test.db.TestLinkedTable;
import org.h2.test.db.TestListener; import org.h2.test.db.TestListener;
import org.h2.test.db.TestLob; import org.h2.test.db.TestLob;
import org.h2.test.db.TestMemoryUsage; import org.h2.test.db.TestMemoryUsage;
import org.h2.test.db.TestMergeUsing;
import org.h2.test.db.TestMultiConn; import org.h2.test.db.TestMultiConn;
import org.h2.test.db.TestMultiDimension; import org.h2.test.db.TestMultiDimension;
import org.h2.test.db.TestMultiThread; import org.h2.test.db.TestMultiThread;
...@@ -749,6 +750,7 @@ kill -9 `jps -l | grep "org.h2.test." | cut -d " " -f 1` ...@@ -749,6 +750,7 @@ kill -9 `jps -l | grep "org.h2.test." | cut -d " " -f 1`
addTest(new TestLinkedTable()); addTest(new TestLinkedTable());
addTest(new TestListener()); addTest(new TestListener());
addTest(new TestLob()); addTest(new TestLob());
addTest(new TestMergeUsing());
addTest(new TestMultiConn()); addTest(new TestMultiConn());
addTest(new TestMultiDimension()); addTest(new TestMultiDimension());
addTest(new TestMultiThreadedKernel()); addTest(new TestMultiThreadedKernel());
......
package org.h2.test.db;
/*
* Copyright 2004-2014 H2 Group. Multiple-Licensed under the MPL 2.0,
* and the EPL 1.0 (http://h2database.com/html/license.html).
* Initial Developer: H2 Group
*/
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import org.h2.api.Trigger;
import org.h2.test.TestBase;
/**
* Test merge using syntax.
*/
public class TestMergeUsing extends TestBase implements Trigger {
private static final String GATHER_ORDERED_RESULTS_SQL = "SELECT ID, NAME FROM PARENT ORDER BY ID ASC";
private static int triggerTestingUpdateCount = 0;
/**
* Run just this test.
*
* @param a ignored
*/
public static void main(String... a) throws Exception {
TestBase.createCaller().init().test();
}
private String triggerName;
@Override
public void test() throws Exception {
// Simple ID,NAME inserts, target table with PK initially empty
testMergeUsing(
"CREATE TABLE PARENT(ID INT, NAME VARCHAR, PRIMARY KEY(ID) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) ) AS S ON (P.ID = S.ID AND 1=1 AND S.ID = P.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME WHERE 2 = 2 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2)",
2
);
// Simple NAME updates, target table missing PK
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) ) AS S ON (P.ID = S.ID AND 1=1 AND S.ID = P.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE 1 = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(1,2)",
2
);
// No NAME updates, WHERE clause is always false, insert clause missing
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE 1 = 2",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2)",
0
);
// No NAME updates, no WHERE clause, insert clause missing
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(1,2)",
2
);
// Two delete updates done, no WHERE clause, insert clause missing
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN DELETE",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) WHERE 1=0",
2
);
// One insert, one update one delete happens, target table missing PK
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE P.ID = 2 DELETE WHERE P.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3
);
// No updates happen: No insert defined, no update or delete happens due to ON condition failing always, target table missing PK
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) ) AS S ON (P.ID = S.ID AND 1=0) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE P.ID = 2 DELETE WHERE P.ID = 1",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2)",
0
);
// One insert, one update one delete happens, target table missing PK
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT AS P USING SOURCE AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE P.ID = 2 DELETE WHERE P.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3
);
// One insert, one update one delete happens, target table missing PK, no source alias
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT AS P USING SOURCE ON (P.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET P.NAME = SOURCE.NAME||SOURCE.ID WHERE P.ID = 2 DELETE WHERE P.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3
);
// One insert, one update one delete happens, target table missing PK, no source or target alias
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3
);
// Only insert clause, no update or delete clauses
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) );"+
"DELETE FROM PARENT;",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) ) AS S ON (P.ID = S.ID) WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3)",
3
);
// no insert, no update, no delete clauses - essentially a no-op
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) );"+
"DELETE FROM PARENT;",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) ) AS S ON (P.ID = S.ID)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) WHERE X<0",
0,
"At least UPDATE, DELETE or INSERT embedded statement must be supplied."
);
// Two updates to same row - update and delete together - emptying the parent table
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) )",
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = P.NAME||S.ID WHERE P.ID = 1 DELETE WHERE P.ID = 1 AND P.NAME = 'Marcy11'",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) WHERE X<0",
2
);
// Duplicate source keys but different ROWID update - so no error
// SQL standard says duplicate or repeated updates of same row in same statement should cause errors - but because first row is updated, deleted (on source row 1) then inserted (on source row 2)
// it's considered different - with respect to to ROWID - so no error
// One insert, one update one delete happens (on same row) , target table missing PK, no source or target alias
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) );"+
"CREATE TABLE SOURCE AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT 1 AS ID, 'Marcy'||X||X UNION ALL SELECT 1 AS ID, 'Marcy2'",
2
);
// Multiple update on same row: SQL standard says duplicate or repeated updates in same statement should cause errors -but because first row is updated, delete then insert it's considered different
// One insert, one update one delete happens (on same row, which is okay), then another update (which is illegal)target table missing PK, no source or target alias
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,1) );"+
"CREATE TABLE SOURCE AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT 1 AS ID, 'Marcy'||X||X UNION ALL SELECT 1 AS ID, 'Marcy2'",
3,
"Unique index or primary key violation: \"Merge using ON column expression, duplicate _ROWID_ target record already updated, deleted or inserted:_ROWID_=2:in:PUBLIC.PARENT:conflicting source row number:2"
);
// Duplicate key updated 3 rows at once, only 1 expected
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3,
"Duplicate key updated 3 rows at once, only 1 expected"
);
// Missing target columns in ON expression
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (1 = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3,
"No references to target columns found in ON clause"
);
// Missing source columns in ON expression
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = 1) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X||X AS NAME FROM SYSTEM_RANGE(2,2) UNION ALL SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(3,3)",
3,
"No references to source columns found in ON clause"
);
// Insert does not insert correct values with respect to ON condition (inserts ID value above 100, instead)
testMergeUsingException(
"CREATE TABLE PARENT AS (SELECT 1 AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(4,4) );"+
"CREATE TABLE SOURCE AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,3) );",
"MERGE INTO PARENT USING SOURCE ON (PARENT.ID = SOURCE.ID) WHEN MATCHED THEN UPDATE SET PARENT.NAME = SOURCE.NAME||SOURCE.ID WHERE PARENT.ID = 2 DELETE WHERE PARENT.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (SOURCE.ID+100, SOURCE.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(4,4)",
1,
"Expected to find key after row inserted, but none found. Insert does not match ON condition."
);
// One insert, one update one delete happens, target table missing PK, triggers update all NAME fields
triggerTestingUpdateCount=0;
testMergeUsing(
"CREATE TABLE PARENT AS (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,2));"
+getCreateTriggerSQL(),
"MERGE INTO PARENT AS P USING (SELECT X AS ID, 'Marcy'||X AS NAME FROM SYSTEM_RANGE(1,4) ) AS S ON (P.ID = S.ID) WHEN MATCHED THEN UPDATE SET P.NAME = S.NAME||S.ID WHERE P.ID = 2 DELETE WHERE P.ID = 1 WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)",
GATHER_ORDERED_RESULTS_SQL,
"SELECT 2 AS ID, 'Marcy22-updated2' AS NAME UNION ALL SELECT X AS ID, 'Marcy'||X||'-inserted'||X AS NAME FROM SYSTEM_RANGE(3,4)",
4
);
}
/**
* Run a test case of the merge using syntax
* @param setupSQL - one or more SQL statements to setup the case
* @param statementUnderTest - the merge statement being tested
* @param gatherResultsSQL - a select which gathers the results of the merge from the target table
* @param expectedResultsSQL - a select which returns the expected results in the target table
* @param expectedRowUpdateCount - how many updates should be expected from the merge using
* @throws Exception
*/
private void testMergeUsing(String setupSQL, String statementUnderTest, String gatherResultsSQL,
String expectedResultsSQL, int expectedRowUpdateCount) throws Exception {
deleteDb("mergeUsingQueries");
Connection conn = getConnection("mergeUsingQueries");
Statement stat;
PreparedStatement prep;
ResultSet rs;
int rowCountUpdate;
try{
stat = conn.createStatement();
stat.execute(setupSQL);
prep = conn.prepareStatement(statementUnderTest);
rowCountUpdate = prep.executeUpdate();
// compare actual results from SQL resultsset with expected results - by diffing (aka set MINUS operation)
rs = stat.executeQuery("( "+gatherResultsSQL+" ) MINUS ( "+expectedResultsSQL+" )");
int rowCount = 0;
StringBuffer diffBuffer = new StringBuffer("");
while (rs.next()) {
rowCount++;
diffBuffer.append("|");
for(int ndx = 1; ndx <= rs.getMetaData().getColumnCount(); ndx++){
diffBuffer.append(rs.getObject(ndx));
diffBuffer.append("|\n");
}
}
assertEquals("Differences between expected and actual output found:"+diffBuffer,0,rowCount);
assertEquals("Expected update counts differ",expectedRowUpdateCount,rowCountUpdate);
}
finally{
conn.close();
deleteDb("mergeUsingQueries");
}
}
/**
* Run a test case of the merge using syntax
* @param setupSQL - one or more SQL statements to setup the case
* @param statementUnderTest - the merge statement being tested
* @param gatherResultsSQL - a select which gathers the results of the merge from the target table
* @param expectedResultsSQL - a select which returns the expected results in the target table
* @param expectedRowUpdateCount - how many updates should be expected from the merge using
* @param exceptionMessage - the exception message expected
* @throws Exception
*/
private void testMergeUsingException(String setupSQL, String statementUnderTest, String gatherResultsSQL,
String expectedResultsSQL, int expectedRowUpdateCount, String exceptionMessage) throws Exception {
try{
testMergeUsing( setupSQL, statementUnderTest, gatherResultsSQL,
expectedResultsSQL, expectedRowUpdateCount);
}
catch(RuntimeException|org.h2.jdbc.JdbcSQLException e){
if(!e.getMessage().contains(exceptionMessage)){
e.printStackTrace();
}
assertContains(e.getMessage(),exceptionMessage);
return;
}
fail("Failed to see exception with message:"+exceptionMessage);
}
@Override
public void fire(Connection conn, Object[] oldRow, Object[] newRow)
throws SQLException {
if (conn == null) {
throw new AssertionError("connection is null");
}
if (triggerName.startsWith("INS_BEFORE")) {
newRow[1] = newRow[1] + "-inserted"+(++triggerTestingUpdateCount);
} else if (triggerName.startsWith("UPD_BEFORE")) {
newRow[1] = newRow[1] + "-updated"+(++triggerTestingUpdateCount);
} else if (triggerName.startsWith("DEL_BEFORE")) {
oldRow[1] = oldRow[1] + "-deleted"+(++triggerTestingUpdateCount);
}
}
@Override
public void close() {
// ignore
}
@Override
public void remove() {
// ignore
}
@Override
public void init(Connection conn, String schemaName, String trigger,
String tableName, boolean before, int type) {
this.triggerName = trigger;
if (!"PARENT".equals(tableName)) {
throw new AssertionError("supposed to be PARENT");
}
if ((trigger.endsWith("AFTER") && before) ||
(trigger.endsWith("BEFORE") && !before)) {
throw new AssertionError("triggerName: " + trigger + " before:" + before);
}
if ((trigger.startsWith("UPD") && type != UPDATE) ||
(trigger.startsWith("INS") && type != INSERT) ||
(trigger.startsWith("DEL") && type != DELETE)) {
throw new AssertionError("triggerName: " + trigger + " type:" + type);
}
}
private String getCreateTriggerSQL(){
StringBuffer buf = new StringBuffer();
buf.append("CREATE TRIGGER INS_BEFORE " +
"BEFORE INSERT ON PARENT " +
"FOR EACH ROW NOWAIT CALL \"" + getClass().getName() + "\";");
buf.append("CREATE TRIGGER UPD_BEFORE " +
"BEFORE UPDATE ON PARENT " +
"FOR EACH ROW NOWAIT CALL \"" + getClass().getName() + "\";");
buf.append("CREATE TRIGGER DEL_BEFORE " +
"BEFORE DELETE ON PARENT " +
"FOR EACH ROW NOWAIT CALL \"" + getClass().getName() + "\";");
return buf.toString();
}
}
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论