提交 8dd0a0b1 authored 作者: Andrei Tokar's avatar Andrei Tokar

Merge remote-tracking branch 'h2database/master' into issue_1479

# Conflicts:
#	h2/src/main/org/h2/command/dml/Delete.java
#	h2/src/main/org/h2/command/dml/Update.java
......@@ -82,7 +82,7 @@ UPDATE PERSON P SET NAME=(SELECT A.NAME FROM ADDRESS A WHERE A.ID=P.ID);
"
"Commands (DML)","DELETE","
DELETE [ TOP term ] FROM tableName deleteSearchCondition
DELETE [ TOP term ] FROM tableName [ WHERE expression ] [ LIMIT term ]
","
Deletes rows form a table.
If TOP or LIMIT is specified, at most the specified number of rows are deleted (no limit if null or smaller than zero).
......@@ -137,36 +137,34 @@ MERGE INTO TEST KEY(ID) VALUES(2, 'World')
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
ON expression
[ WHEN MATCHED THEN
[ UPDATE SET setClauseList ] [ DELETE deleteSearchCondition ] ]
[ WHEN NOT MATCHED THEN INSERT insertColumnsAndSource ]
","
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.
WHEN MATCHED THEN or WHEN NOT MATCHED THEN clauses or both of them in any order should be specified.
If WHEN MATCHED THEN is specified it should contain UPDATE or DELETE clauses of both of them.
mergeWhenClause [,...]
","
Updates or deletes existing rows, and insert rows that don't exist.
The ON clause specifies the matching column expression.
Different rows from a source table may not match with the same target row,
but one source row may be matched with multiple target rows.
If statement doesn't need a source table a DUAL table can be substituted.
","
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 MATCHED AND T.COL2 <> 'FINAL' THEN
UPDATE SET T.COL1 = S.COL1
WHEN MATCHED AND T.COL2 = 'FINAL' THEN
DELETE
WHEN NOT MATCHED THEN
INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
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 MATCHED AND T.COL2 <> 'FINAL' THEN
UPDATE SET T.COL1 = S.COL1
WHEN MATCHED AND T.COL2 = 'FINAL' THEN
DELETE
WHEN NOT MATCHED THEN
INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
INSERT VALUES (S.ID, S.COL1, S.COL2)
MERGE INTO TARGET_TABLE USING DUAL ON ID = 1
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (1, 'Test')
WHEN NOT MATCHED THEN INSERT VALUES (1, 'Test')
WHEN MATCHED THEN UPDATE SET NAME = 'Test'
"
......@@ -2277,14 +2275,6 @@ SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
"
"Other Grammar","Delete search condition","
[ WHERE expression ] [ LIMIT term ]
","
Search condition for DELETE statement.
","
WHERE ID = 2
"
"Other Grammar","Digit","
0-9
","
......@@ -2373,6 +2363,38 @@ Long numbers are between -9223372036854775808 and 9223372036854775807.
100000
"
"Other Grammar","Merge when clause","
mergeWhenMatchedClause|mergeWhenNotMatchedClause
","
WHEN MATCHED or WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN MATCHED THEN DELETE
"
"Other Grammar","Merge when matched clause","
WHEN MATCHED [ AND expression ] THEN
UPDATE SET setClauseList
| DELETE
| {UPDATE SET setClauseList [ WHERE expression ] DELETE [ WHERE expression ]}
","
WHEN MATCHED clause for MERGE USING command.
If both UPDATE and DELETE are specified, DELETE can delete only rows that were updated,
WHERE condition in DELETE clause can be used to specify which updated rows should be deleted.
This condition checks values in updated row.
","
WHEN MATCHED THEN UPDATE SET VALUE = S.VALUE
WHEN MATCHED THEN DELETE
"
"Other Grammar","Merge when not matched clause","
WHEN NOT MATCHED [ AND expression ] THEN INSERT insertColumnsAndSource
","
WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)
"
"Other Grammar","Name","
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
","
......@@ -2496,8 +2518,8 @@ START WITH 1
"
"Other Grammar","Set clause list","
{ { columnName = { DEFAULT | expression } } [,...] } |
{ ( columnName [,...] ) = ( select ) }
{ { columnName = { DEFAULT | expression } } [,...] }
| { ( columnName [,...] ) = ( select ) }
","
List of SET clauses.
","
......
......@@ -21,6 +21,8 @@ Change Log
<h2>Next Version (unreleased)</h2>
<ul>
<li>Issue #1495: MERGE statement doesn't affect any rows when Oracle UPDATE .. WHERE .. DELETE .. WHERE is used
</li>
<li>Issue #1493: MERGE statement fails when it updates more than one row
</li>
<li>Issue #1492: Unnecessary restriction on MERGE USING statement when ON clause doesn't reference any target table columns
......@@ -29,6 +31,8 @@ Change Log
</li>
<li>Issue #1490: NullPointerException when running invalid MERGE statement
</li>
<li>Issue #1489: MERGE USING documentation has misleading railroad diagram
</li>
<li>Issue #1488: Improve documentation of window and some other functions
</li>
<li>Issue #1485: Default window frame in presence of ORDER BY is RANGE .., not ROWS
......
......@@ -1116,11 +1116,11 @@ public class Parser {
int start = lastParseIndex;
TableFilter filter = readSimpleTableFilter(0, null);
command.setTableFilter(filter);
parseUpdateSetClause(command, filter, start);
parseUpdateSetClause(command, filter, start, true);
return command;
}
private void parseUpdateSetClause(Update command, TableFilter filter, int start) {
private void parseUpdateSetClause(Update command, TableFilter filter, int start, boolean allowExtensions) {
read("SET");
if (readIf(OPEN_PAREN)) {
ArrayList<Column> columns = Utils.newSmallArrayList();
......@@ -1154,15 +1154,17 @@ public class Parser {
Expression condition = readExpression();
command.setCondition(condition);
}
if (readIf(ORDER)) {
// for MySQL compatibility
// (this syntax is supported, but ignored)
read("BY");
parseSimpleOrderList();
}
if (readIf(LIMIT)) {
Expression limit = readTerm().optimize(session);
command.setLimit(limit);
if (allowExtensions) {
if (readIf(ORDER)) {
// for MySQL compatibility
// (this syntax is supported, but ignored)
read("BY");
parseSimpleOrderList();
}
if (readIf(LIMIT)) {
Expression limit = readTerm().optimize(session);
command.setLimit(limit);
}
}
setSQL(command, "UPDATE", start);
}
......@@ -1197,20 +1199,15 @@ public class Parser {
}
TableFilter filter = readSimpleTableFilter(0, null);
command.setTableFilter(filter);
parseDeleteGivenTable(command, limit, start);
return command;
}
private void parseDeleteGivenTable(Delete command, Expression limit, int start) {
if (readIf(WHERE)) {
Expression condition = readExpression();
command.setCondition(condition);
command.setCondition(readExpression());
}
if (readIf(LIMIT) && limit == null) {
if (limit == null && readIf(LIMIT)) {
limit = readTerm().optimize(session);
}
command.setLimit(limit);
setSQL(command, "DELETE", start);
return command;
}
private IndexColumn[] parseIndexColumnList() {
......@@ -1496,47 +1493,47 @@ public class Parser {
command.setOnCondition(condition);
read("WHEN");
boolean matched = readIf("MATCHED");
if (matched) {
parseWhenMatched(command);
} else {
parseWhenNotMatched(command);
}
if (readIf("WHEN")) {
do {
boolean matched = readIf("MATCHED");
if (matched) {
parseWhenNotMatched(command);
} else {
read("MATCHED");
parseWhenMatched(command);
} else {
parseWhenNotMatched(command);
}
}
} while (readIf("WHEN"));
setSQL(command, "MERGE", start);
return command;
}
private void parseWhenMatched(MergeUsing command) {
Expression and = readIf("AND") ? readExpression() : null;
read("THEN");
int startMatched = lastParseIndex;
boolean ok = false;
Update updateCommand = null;
if (readIf("UPDATE")) {
Update updateCommand = new Update(session);
updateCommand = new Update(session);
TableFilter filter = command.getTargetTableFilter();
updateCommand.setTableFilter(filter);
parseUpdateSetClause(updateCommand, filter, startMatched);
command.setUpdateCommand(updateCommand);
ok = true;
parseUpdateSetClause(updateCommand, filter, startMatched, false);
startMatched = lastParseIndex;
}
startMatched = lastParseIndex;
Delete deleteCommand = null;
if (readIf("DELETE")) {
Delete deleteCommand = new Delete(session);
TableFilter filter = command.getTargetTableFilter();
deleteCommand.setTableFilter(filter);
parseDeleteGivenTable(deleteCommand, null, startMatched);
command.setDeleteCommand(deleteCommand);
ok = true;
}
if (!ok) {
deleteCommand = new Delete(session);
deleteCommand.setTableFilter(command.getTargetTableFilter());
if (readIf(WHERE)) {
deleteCommand.setCondition(readExpression());
}
setSQL(deleteCommand, "DELETE", startMatched);
}
if (updateCommand != null || deleteCommand != null) {
MergeUsing.WhenMatched when = new MergeUsing.WhenMatched(command);
when.setAndCondition(and);
when.setUpdateCommand(updateCommand);
when.setDeleteCommand(deleteCommand);
command.addWhen(when);
} else {
throw getSyntaxError();
}
}
......@@ -1544,12 +1541,16 @@ public class Parser {
private void parseWhenNotMatched(MergeUsing command) {
read(NOT);
read("MATCHED");
Expression and = readIf("AND") ? readExpression() : null;
read("THEN");
if (readIf("INSERT")) {
Insert insertCommand = new Insert(session);
insertCommand.setTable(command.getTargetTable());
parseInsertGivenTable(insertCommand, command.getTargetTable());
command.setInsertCommand(insertCommand);
MergeUsing.WhenNotMatched when = new MergeUsing.WhenNotMatched(command);
when.setAndCondition(and);
when.setInsertCommand(insertCommand);
command.addWhen(when);
} else {
throw getSyntaxError();
}
......
......@@ -5,6 +5,8 @@
*/
package org.h2.command.dml;
import java.util.HashSet;
import org.h2.api.Trigger;
import org.h2.command.CommandInterface;
import org.h2.command.Prepared;
......@@ -40,6 +42,8 @@ public class Delete extends Prepared {
*/
private TableFilter sourceTableFilter;
private HashSet<Long> keysFilter;
public Delete(Session session) {
super(session);
}
......@@ -56,6 +60,15 @@ public class Delete extends Prepared {
return this.condition;
}
/**
* Sets the keys filter.
*
* @param keysFilter the keys filter
*/
public void setKeysFilter(HashSet<Long> keysFilter) {
this.keysFilter = keysFilter;
}
@Override
public int update() {
targetTableFilter.startQuery(session);
......@@ -79,21 +92,23 @@ public class Delete extends Prepared {
setCurrentRowNumber(rows.size() + 1);
if (condition == null || condition.getBooleanValue(session)) {
Row row = targetTableFilter.get();
boolean done = false;
if (table.fireRow()) {
done = table.fireBeforeRow(session, row, null);
}
if (!done) {
if (table.isMVStore()) {
done = table.lockRow(session, row) == null;
if (keysFilter == null || keysFilter.contains(row.getKey())) {
boolean done = false;
if (table.fireRow()) {
done = table.fireBeforeRow(session, row, null);
}
if (!done) {
rows.add(row);
if (table.isMVStore()) {
done = table.lockRow(session, row) == null;
}
if (!done) {
rows.add(row);
}
}
count++;
if (limitRows >= 0 && count >= limitRows) {
break;
}
}
count++;
if (limitRows >= 0 && count >= limitRows) {
break;
}
}
}
......
......@@ -7,6 +7,7 @@ package org.h2.command.dml;
import java.util.ArrayList;
import java.util.HashMap;
import java.util.HashSet;
import org.h2.api.ErrorCode;
import org.h2.api.Trigger;
......@@ -14,6 +15,7 @@ import org.h2.command.CommandInterface;
import org.h2.command.Prepared;
import org.h2.engine.Right;
import org.h2.engine.Session;
import org.h2.engine.User;
import org.h2.expression.ConditionAndOr;
import org.h2.expression.Expression;
import org.h2.expression.ExpressionColumn;
......@@ -21,7 +23,6 @@ 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.StatementBuilder;
......@@ -32,83 +33,206 @@ import org.h2.value.Value;
* This class represents the statement syntax
* MERGE INTO 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 NEVER 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.
* It does not replace the MERGE INTO... KEYS... form.
*/
public class MergeUsing extends Prepared {
public static abstract class When {
final MergeUsing mergeUsing;
Expression andCondition;
When(MergeUsing mergeUsing) {
this.mergeUsing = mergeUsing;
}
/**
* Sets the specified AND condition.
*
* @param andCondition AND condition to set
*/
public void setAndCondition(Expression andCondition) {
this.andCondition = andCondition;
}
void reset() {
// Nothing to do
}
abstract int merge();
void prepare() {
if (andCondition != null) {
andCondition.mapColumns(mergeUsing.sourceTableFilter, 2, Expression.MAP_INITIAL);
andCondition.mapColumns(mergeUsing.targetTableFilter, 1, Expression.MAP_INITIAL);
}
}
abstract int evaluateTriggerMasks();
abstract void checkRights();
}
public static final class WhenMatched extends When {
private Update updateCommand;
private Delete deleteCommand;
private final HashSet<Long> updatedKeys = new HashSet<>();
public WhenMatched(MergeUsing mergeUsing) {
super(mergeUsing);
}
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;
}
@Override
void reset() {
updatedKeys.clear();
}
@Override
int merge() {
int countUpdatedRows = 0;
if (updateCommand != null) {
countUpdatedRows += updateCommand.update();
}
// under oracle rules these updates & delete combinations are
// allowed together
if (deleteCommand != null) {
countUpdatedRows += deleteCommand.update();
updatedKeys.clear();
}
return countUpdatedRows;
}
@Override
void prepare() {
super.prepare();
if (updateCommand != null) {
updateCommand.setSourceTableFilter(mergeUsing.sourceTableFilter);
updateCommand.setCondition(appendCondition(updateCommand, mergeUsing.onCondition));
if (andCondition != null) {
updateCommand.setCondition(appendCondition(updateCommand, andCondition));
}
updateCommand.prepare();
}
if (deleteCommand != null) {
deleteCommand.setSourceTableFilter(mergeUsing.sourceTableFilter);
deleteCommand.setCondition(appendCondition(deleteCommand, mergeUsing.onCondition));
if (andCondition != null) {
deleteCommand.setCondition(appendCondition(deleteCommand, andCondition));
}
deleteCommand.prepare();
if (updateCommand != null) {
updateCommand.setUpdatedKeysCollector(updatedKeys);
deleteCommand.setKeysFilter(updatedKeys);
}
}
}
@Override
int evaluateTriggerMasks() {
int masks = 0;
if (updateCommand != null) {
masks |= Trigger.UPDATE;
}
if (deleteCommand != null) {
masks |= Trigger.DELETE;
}
return masks;
}
@Override
void checkRights() {
User user = mergeUsing.getSession().getUser();
if (updateCommand != null) {
user.checkRight(mergeUsing.targetTable, Right.UPDATE);
}
if (deleteCommand != null) {
user.checkRight(mergeUsing.targetTable, Right.DELETE);
}
}
private static Expression appendCondition(Update updateCommand, Expression condition) {
Expression c = updateCommand.getCondition();
return c == null ? condition : new ConditionAndOr(ConditionAndOr.AND, c, condition);
}
private static Expression appendCondition(Delete deleteCommand, Expression condition) {
Expression c = deleteCommand.getCondition();
return c == null ? condition : new ConditionAndOr(ConditionAndOr.AND, c, condition);
}
}
public static final class WhenNotMatched extends When {
private Insert insertCommand;
public WhenNotMatched(MergeUsing mergeUsing) {
super(mergeUsing);
}
public Insert getInsertCommand() {
return insertCommand;
}
public void setInsertCommand(Insert insertCommand) {
this.insertCommand = insertCommand;
}
@Override
int merge() {
return andCondition == null || andCondition.getBooleanValue(mergeUsing.getSession()) ?
insertCommand.update() : 0;
}
@Override
void prepare() {
super.prepare();
insertCommand.setSourceTableFilter(mergeUsing.sourceTableFilter);
insertCommand.prepare();
}
@Override
int evaluateTriggerMasks() {
return Trigger.INSERT;
}
@Override
void checkRights() {
mergeUsing.getSession().getUser().checkRight(mergeUsing.targetTable, Right.INSERT);
}
}
// Merge fields
private Table targetTable;
private TableFilter targetTableFilter;
private Column[] columns;
private final ArrayList<Expression[]> valuesExpressionList = Utils.newSmallArrayList();
Table targetTable;
TableFilter targetTableFilter;
private Query query;
// MergeUsing fields
private TableFilter sourceTableFilter;
private Expression onCondition;
private Update updateCommand;
private Delete deleteCommand;
private Insert insertCommand;
TableFilter sourceTableFilter;
Expression onCondition;
private ArrayList<When> when = Utils.newSmallArrayList();
private String queryAlias;
private int countUpdatedRows;
private Select targetMatchQuery;
......@@ -129,20 +253,18 @@ public class MergeUsing extends Prepared {
// clear list of source table keys & rowids we have processed already
targetRowidsRemembered.clear();
if (targetTableFilter != null) {
targetTableFilter.startQuery(session);
targetTableFilter.reset();
}
targetTableFilter.startQuery(session);
targetTableFilter.reset();
if (sourceTableFilter != null) {
sourceTableFilter.startQuery(session);
sourceTableFilter.reset();
}
sourceTableFilter.startQuery(session);
sourceTableFilter.reset();
sourceQueryRowNumber = 0;
checkRights();
setCurrentRowNumber(0);
for (When w : when) {
w.reset();
}
// process source select query data for row creation
ResultInterface rows = query.query(0);
targetTable.fire(session, evaluateTriggerMasks(), true);
......@@ -162,33 +284,19 @@ public class MergeUsing extends Prepared {
private int evaluateTriggerMasks() {
int masks = 0;
if (insertCommand != null) {
masks |= Trigger.INSERT;
}
if (updateCommand != null) {
masks |= Trigger.UPDATE;
}
if (deleteCommand != null) {
masks |= Trigger.DELETE;
for (When w : when) {
masks |= w.evaluateTriggerMasks();
}
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);
for (When w : when) {
w.checkRights();
}
// check the underlying tables
session.getUser().checkRight(targetTable, Right.SELECT);
session.getUser().checkRight(sourceTableFilter.getTable(),
Right.SELECT);
session.getUser().checkRight(sourceTableFilter.getTable(), Right.SELECT);
}
/**
......@@ -199,18 +307,10 @@ public class MergeUsing extends Prepared {
protected void merge(Row sourceRow) {
// put the column values into the table filter
sourceTableFilter.set(sourceRow);
if (isTargetRowFound()) {
if (updateCommand != null) {
countUpdatedRows += updateCommand.update();
}
// under oracle rules these updates & delete combinations are
// allowed together
if (deleteCommand != null) {
countUpdatedRows += deleteCommand.update();
}
} else {
if (insertCommand != null) {
countUpdatedRows += insertCommand.update();
boolean found = isTargetRowFound();
for (When w : when) {
if (w.getClass() == WhenNotMatched.class ^ found) {
countUpdatedRows += w.merge();
}
}
}
......@@ -241,38 +341,11 @@ public class MergeUsing extends Prepared {
return matched;
}
// 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(')').append('\n');
if (!valuesExpressionList.isEmpty()) {
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());
}
buff.append(targetTable.getSQL()).append('\n').append("USING ").append(query.getPlanSQL());
// TODO add aliases and WHEN clauses to make plan SQL more like original SQL
return buff.toString();
}
......@@ -290,47 +363,13 @@ public class MergeUsing extends Prepared {
onCondition.createIndexConditions(session, sourceTableFilter);
onCondition.createIndexConditions(session, targetTableFilter);
if (columns == null) {
if (!valuesExpressionList.isEmpty()
&& valuesExpressionList.get(0).length == 0) {
// special case where table is used as a sequence
columns = new Column[0];
} else {
columns = targetTable.getColumns();
}
}
if (!valuesExpressionList.isEmpty()) {
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();
}
query.prepare();
// 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();
}
if (deleteCommand != null) {
deleteCommand.setSourceTableFilter(sourceTableFilter);
deleteCommand.setCondition(appendOnCondition(deleteCommand));
deleteCommand.prepare();
}
if (insertCommand != null) {
insertCommand.setSourceTableFilter(sourceTableFilter);
insertCommand.prepare();
targetTableFilter.doneWithIndexConditions();
for (When w : when) {
w.prepare();
}
// setup the targetMatchQuery - for detecting if the target row exists
......@@ -345,22 +384,6 @@ public class MergeUsing extends Prepared {
targetMatchQuery.prepare();
}
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;
}
......@@ -377,28 +400,12 @@ public class MergeUsing extends Prepared {
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 ArrayList<When> getWhen() {
return when;
}
public void setInsertCommand(Insert insertCommand) {
this.insertCommand = insertCommand;
public void addWhen(When w) {
when.add(w);
}
public void setQueryAlias(String alias) {
......
......@@ -7,6 +7,7 @@ package org.h2.command.dml;
import java.util.ArrayList;
import java.util.HashMap;
import java.util.HashSet;
import java.util.Objects;
import org.h2.api.ErrorCode;
......@@ -53,6 +54,8 @@ public class Update extends Prepared {
private final ArrayList<Column> columns = Utils.newSmallArrayList();
private final HashMap<Column, Expression> expressionMap = new HashMap<>();
private HashSet<Long> updatedKeysCollector;
public Update(Session session) {
super(session);
}
......@@ -88,6 +91,15 @@ public class Update extends Prepared {
}
}
/**
* Sets the collector of updated keys.
*
* @param updatedKeysCollector the collector of updated keys
*/
public void setUpdatedKeysCollector(HashSet<Long> updatedKeysCollector) {
this.updatedKeysCollector = updatedKeysCollector;
}
@Override
public int update() {
targetTableFilter.startQuery(session);
......@@ -135,7 +147,8 @@ public class Update extends Prepared {
}
newRow.setValue(i, newValue);
}
newRow.setKey(oldRow.getKey());
long key = oldRow.getKey();
newRow.setKey(key);
if (setOnUpdate || updateToCurrentValuesReturnsZero) {
setOnUpdate = false;
for (int i = 0; i < columnCount; i++) {
......@@ -170,6 +183,9 @@ public class Update extends Prepared {
if (!done) {
rows.add(oldRow);
rows.add(newRow);
if (updatedKeysCollector != null) {
updatedKeysCollector.add(key);
}
}
}
count++;
......
......@@ -82,6 +82,11 @@ public class TableFilter implements ColumnResolver {
*/
private final ArrayList<IndexCondition> indexConditions = Utils.newSmallArrayList();
/**
* Whether new window conditions should not be accepted.
*/
private boolean doneWithIndexConditions;
/**
* Additional conditions that can't be used for index lookup, but for row
* filter for this table (ID=ID, NAME LIKE '%X%')
......@@ -627,7 +632,16 @@ public class TableFilter implements ColumnResolver {
* @param condition the index condition
*/
public void addIndexCondition(IndexCondition condition) {
indexConditions.add(condition);
if (!doneWithIndexConditions) {
indexConditions.add(condition);
}
}
/**
* Used to reject all additional index conditions.
*/
public void doneWithIndexConditions() {
this.doneWithIndexConditions = true;
}
/**
......
......@@ -96,7 +96,7 @@ public class TestMergeUsing extends TestDb implements Trigger {
"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 " +
"WHEN MATCHED THEN 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 " +
......@@ -116,8 +116,9 @@ public class TestMergeUsing extends TestDb implements Trigger {
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 " +
"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 " +
"WHEN MATCHED THEN 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 " +
......@@ -128,8 +129,9 @@ public class TestMergeUsing extends TestDb implements Trigger {
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 " +
"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 " +
"WHEN MATCHED THEN 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 " +
......@@ -140,9 +142,10 @@ public class TestMergeUsing extends TestDb implements Trigger {
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)",
"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 " +
"WHEN MATCHED THEN 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)",
......@@ -185,6 +188,7 @@ public class TestMergeUsing extends TestDb implements Trigger {
// 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
if (false) // TODO
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) );",
......@@ -205,7 +209,8 @@ public class TestMergeUsing extends TestDb implements Trigger {
"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)",
"WHEN MATCHED THEN 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)",
......
......@@ -29,7 +29,7 @@ EXPLAIN PLAN
UPDATE SET P.NAME = S.NAME WHERE 2 = 2 WHEN NOT
MATCHED THEN
INSERT (ID, NAME) VALUES (S.ID, S.NAME);
>> MERGE INTO PUBLIC.PARENT(ID, NAME) SELECT X AS ID, ('Coco' || X) AS NAME FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */
>> MERGE INTO PUBLIC.PARENT USING SELECT X AS ID, ('Coco' || X) AS NAME FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */
DROP TABLE PARENT;
> ok
......@@ -259,5 +259,66 @@ SELECT * FROM TEST;
> 3 50
> rows: 3
MERGE INTO TEST USING (SELECT 1) ON 1 = 1
WHEN MATCHED THEN UPDATE SET VALUE = 60 WHERE ID = 3 DELETE WHERE ID = 2;
> update count: 1
SELECT * FROM TEST;
> ID VALUE
> -- -----
> 1 50
> 2 50
> 3 60
> rows: 3
MERGE INTO TEST USING (SELECT 1) ON 1 = 1
WHEN MATCHED THEN DELETE WHERE ID = 2;
> update count: 1
SELECT * FROM TEST;
> ID VALUE
> -- -----
> 1 50
> 3 60
> rows: 2
MERGE INTO TEST USING (SELECT 1) ON 1 = 1
WHEN MATCHED THEN UPDATE SET VALUE = 70 WHERE ID = 3 DELETE WHERE VALUE = 70;
> update count: 2
SELECT * FROM TEST;
> ID VALUE
> -- -----
> 1 50
> rows: 1
DROP TABLE TEST;
> ok
CREATE TABLE T(ID INT, F BOOLEAN, VALUE INT);
> ok
INSERT INTO T VALUES (1, FALSE, 10), (2, TRUE, 20);
> update count: 2
CREATE TABLE S(S_ID INT, S_F BOOLEAN, S_VALUE INT);
> ok
INSERT INTO S VALUES (1, FALSE, 100), (2, TRUE, 200), (3, FALSE, 300), (4, TRUE, 400);
> update count: 4
MERGE INTO T USING S ON ID = S_ID
WHEN MATCHED AND F THEN UPDATE SET VALUE = S_VALUE
WHEN MATCHED AND NOT F THEN DELETE
WHEN NOT MATCHED AND S_F THEN INSERT VALUES (S_ID, S_F, S_VALUE);
> update count: 3
SELECT * FROM T;
> ID F VALUE
> -- ---- -----
> 2 TRUE 200
> 4 TRUE 400
> rows: 2
DROP TABLE T, S;
> ok
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论