提交 31dfacb3 authored 作者: Noel Grandin's avatar Noel Grandin

formatting

上级 5805991d
......@@ -14,7 +14,6 @@ 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;
......@@ -101,7 +100,8 @@ public class MergeUsing extends Prepared {
private TableFilter targetTableFilter;
private Column[] columns;
private Column[] keys;
private final ArrayList<Expression[]> valuesExpressionList = New.arrayList();
private final ArrayList<Expression[]> valuesExpressionList = New
.arrayList();
private Query query;
// MergeUsing fields
......@@ -111,11 +111,11 @@ public class MergeUsing extends Prepared {
private Delete deleteCommand;
private Insert insertCommand;
private String queryAlias;
private int countUpdatedRows=0;
private int countUpdatedRows = 0;
private Column[] sourceKeys;
private Select targetMatchQuery;
private HashMap<Value, Integer> targetRowidsRemembered = new HashMap<>();
private int sourceQueryRowNumber= 0;
private int sourceQueryRowNumber = 0;
public MergeUsing(Merge merge) {
super(merge.getSession());
......@@ -125,19 +125,18 @@ public class MergeUsing extends Prepared {
this.targetTableFilter = merge.getTargetTableFilter();
}
@Override
public int update() {
// clear list of source table keys & rowids we have processed already
targetRowidsRemembered.clear();
if(targetTableFilter!=null){
if (targetTableFilter != null) {
targetTableFilter.startQuery(session);
targetTableFilter.reset();
}
if(sourceTableFilter!=null){
if (sourceTableFilter != null) {
sourceTableFilter.startQuery(session);
sourceTableFilter.reset();
}
......@@ -153,49 +152,49 @@ public class MergeUsing extends Prepared {
while (rows.next()) {
sourceQueryRowNumber++;
Value[] sourceRowValues = rows.currentRow();
Row sourceRow = new RowImpl(sourceRowValues,0);
Row sourceRow = new RowImpl(sourceRowValues, 0);
setCurrentRowNumber(sourceQueryRowNumber);
merge(sourceRow, sourceRowValues);
merge(sourceRow);
}
rows.close();
targetTable.fire(session, evaluateTriggerMasks(), false);
return countUpdatedRows;
}
private int evaluateTriggerMasks() {
int masks = 0;
if(insertCommand!=null){
if (insertCommand != null) {
masks |= Trigger.INSERT;
}
if(updateCommand!=null){
if (updateCommand != null) {
masks |= Trigger.UPDATE;
}
if(deleteCommand!=null){
if (deleteCommand != null) {
masks |= Trigger.DELETE;
}
return masks;
}
private void checkRights() {
if(insertCommand!=null){
if (insertCommand != null) {
session.getUser().checkRight(targetTable, Right.INSERT);
}
if(updateCommand!=null){
if (updateCommand != null) {
session.getUser().checkRight(targetTable, Right.UPDATE);
}
if(deleteCommand!=null){
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);
session.getUser().checkRight(sourceTableFilter.getTable(),
Right.SELECT);
}
protected void merge(Row sourceRow, Value[] sourceRowValues) {
// put the column values into the table filter
protected void merge(Row sourceRow) {
// put the column values into the table filter
sourceTableFilter.set(sourceRow);
// Is the target row there already ?
......@@ -204,73 +203,85 @@ public class MergeUsing extends Prepared {
// try and perform an update
int rowUpdateCount = 0;
if(rowFound){
if(updateCommand!=null){
if (rowFound) {
if (updateCommand != null) {
rowUpdateCount += updateCommand.update();
}
if(deleteCommand!=null){
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{
// under oracle rules these updates & delete combinations are
// allowed together
if (rowUpdateCount == 1 && deleteRowUpdateCount == 1) {
countUpdatedRows += deleteRowUpdateCount;
deleteRowUpdateCount = 0;
} else {
rowUpdateCount += deleteRowUpdateCount;
}
}
}
else
{
} else {
// if either updates do nothing, try an insert
if (rowUpdateCount == 0) {
rowUpdateCount += addRowByCommandInsert(session,sourceRow);
rowUpdateCount += addRowByCommandInsert(sourceRow);
} else if (rowUpdateCount != 1) {
throw DbException.get(ErrorCode.DUPLICATE_KEY_1, "Duplicate key inserted "+rowUpdateCount+" rows at once, only 1 expected:"+targetTable.getSQL());
throw DbException.get(ErrorCode.DUPLICATE_KEY_1,
"Duplicate key inserted " + rowUpdateCount
+ " rows at once, only 1 expected:"
+ targetTable.getSQL());
}
}
countUpdatedRows+=rowUpdateCount;
countUpdatedRows += rowUpdateCount;
}
private boolean isTargetRowFound(){
private boolean isTargetRowFound() {
ResultInterface rows = targetMatchQuery.query(0);
int countTargetRowsFound = 0;
Value[] targetRowIdValue=null;
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
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);
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]));
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;
return countTargetRowsFound > 0;
}
private int addRowByCommandInsert(Session session, Row sourceRow) {
private int addRowByCommandInsert(Row sourceRow) {
int localCount = 0;
if(insertCommand!=null){
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()));
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;
......@@ -330,29 +341,35 @@ public class MergeUsing extends Prepared {
onCondition.mapColumns(targetTableFilter, 1);
if (keys == null) {
HashSet<Column> targetColumns = buildColumnListFromOnCondition(targetTableFilter);
HashSet<Column> targetColumns = buildColumnListFromOnCondition(
targetTableFilter);
keys = targetColumns.toArray(new Column[0]);
}
if(keys.length==0){
if (keys.length == 0) {
throw DbException.get(ErrorCode.COLUMN_NOT_FOUND_1,
"No references to target columns found in ON clause:"+targetTableFilter.toString());
"No references to target columns found in ON clause:"
+ targetTableFilter.toString());
}
if (sourceKeys == null) {
HashSet<Column> sourceColumns = buildColumnListFromOnCondition(sourceTableFilter);
HashSet<Column> sourceColumns = buildColumnListFromOnCondition(
sourceTableFilter);
sourceKeys = sourceColumns.toArray(new Column[0]);
}
if(sourceKeys.length==0){
if (sourceKeys.length == 0) {
throw DbException.get(ErrorCode.COLUMN_NOT_FOUND_1,
"No references to source columns found in ON clause:"+sourceTableFilter.toString());
"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
// 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) {
if (valuesExpressionList.size() > 0
&& valuesExpressionList.get(0).length == 0) {
// special case where table is used as a sequence
columns = new Column[0];
} else {
......@@ -362,7 +379,8 @@ public class MergeUsing extends Prepared {
if (valuesExpressionList.size() > 0) {
for (Expression[] expr : valuesExpressionList) {
if (expr.length != columns.length) {
throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
throw DbException
.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
}
for (int i = 0; i < expr.length; i++) {
Expression e = expr[i];
......@@ -380,26 +398,27 @@ public class MergeUsing extends Prepared {
int embeddedStatementsCount = 0;
// Prepare each of the sub-commands ready to aid in the MERGE collaboration
if(updateCommand!=null){
// 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){
if (deleteCommand != null) {
deleteCommand.setSourceTableFilter(sourceTableFilter);
deleteCommand.setCondition(appendOnCondition(deleteCommand));
deleteCommand.prepare();
embeddedStatementsCount++;
}
if(insertCommand!=null){
if (insertCommand != null) {
insertCommand.setSourceTableFilter(sourceTableFilter);
insertCommand.prepare();
embeddedStatementsCount++;
}
if(embeddedStatementsCount==0){
if (embeddedStatementsCount == 0) {
throw DbException.get(ErrorCode.SYNTAX_ERROR_1,
"At least UPDATE, DELETE or INSERT embedded statement must be supplied.");
}
......@@ -413,13 +432,15 @@ public class MergeUsing extends Prepared {
targetMatchQuery.prepare();
}
private HashSet<Column> buildColumnListFromOnCondition(TableFilter anyTableFilter) {
private HashSet<Column> buildColumnListFromOnCondition(
TableFilter anyTableFilter) {
HashSet<Column> filteredColumns = new HashSet<>();
HashSet<Column> columns = new HashSet<>();
ExpressionVisitor visitor = ExpressionVisitor.getColumnsVisitor(columns);
ExpressionVisitor visitor = ExpressionVisitor
.getColumnsVisitor(columns);
onCondition.isEverything(visitor);
for(Column c: columns){
if(c!=null && c.getTable()==anyTableFilter.getTable()){
for (Column c : columns) {
if (c != null && c.getTable() == anyTableFilter.getTable()) {
filteredColumns.add(c);
}
}
......@@ -427,17 +448,19 @@ public class MergeUsing extends Prepared {
}
private Expression appendOnCondition(Update updateCommand) {
if (updateCommand.getCondition()==null){
if (updateCommand.getCondition() == null) {
return onCondition;
}
return new ConditionAndOr(ConditionAndOr.AND,updateCommand.getCondition(),onCondition);
return new ConditionAndOr(ConditionAndOr.AND,
updateCommand.getCondition(), onCondition);
}
private Expression appendOnCondition(Delete deleteCommand) {
if (deleteCommand.getCondition()==null){
if (deleteCommand.getCondition() == null) {
return onCondition;
}
return new ConditionAndOr(ConditionAndOr.AND,deleteCommand.getCondition(),onCondition);
return new ConditionAndOr(ConditionAndOr.AND,
deleteCommand.getCondition(), onCondition);
}
public void setSourceTableFilter(TableFilter sourceTableFilter) {
......@@ -456,7 +479,6 @@ public class MergeUsing extends Prepared {
return onCondition;
}
public Prepared getUpdateCommand() {
return updateCommand;
}
......@@ -485,10 +507,12 @@ public class MergeUsing extends Prepared {
this.queryAlias = alias;
}
public String getQueryAlias() {
return this.queryAlias;
}
public Query getQuery() {
return query;
}
......
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
*/
package org.h2.test.db;
import java.sql.Connection;
import java.sql.PreparedStatement;
......@@ -12,10 +12,10 @@ 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";
......@@ -40,199 +40,188 @@ public class TestMergeUsing extends TestBase implements Trigger {
"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
);
"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
);
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
);
"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
);
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
);
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
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
);
"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) );",
"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
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) );",
"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
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) );",
"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
);
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;",
"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
);
"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;",
"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
"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
);
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)
// 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
// 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) );",
"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
);
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
// 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) );",
"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"
);
"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) );",
"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"
);
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) );",
"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"
);
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) );",
"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)
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) );",
"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;
"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(),
+ 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
);
}
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
* @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
*/
private void testMergeUsing(String setupSQL, String statementUnderTest, String gatherResultsSQL,
String expectedResultsSQL, int expectedRowUpdateCount) 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;
......@@ -240,58 +229,66 @@ public class TestMergeUsing extends TestBase implements Trigger {
ResultSet rs;
int rowCountUpdate;
try{
try {
stat = conn.createStatement();
stat.execute(setupSQL);
prep = conn.prepareStatement(statementUnderTest);
rowCountUpdate = prep.executeUpdate();
// compare actual results from SQL result set with expected results - by diffing (aka set MINUS operation)
rs = stat.executeQuery("( "+gatherResultsSQL+" ) MINUS ( "+expectedResultsSQL+" )");
// compare actual results from SQL result set 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 i = 1; i <= rs.getMetaData().getColumnCount(); i++){
for (int i = 1; i <= rs.getMetaData().getColumnCount(); i++) {
diffBuffer.append(rs.getObject(i));
diffBuffer.append("|\n");
}
}
assertEquals("Differences between expected and actual output found:"+diffBuffer,0,rowCount);
assertEquals("Expected update counts differ",expectedRowUpdateCount,rowCountUpdate);
}
finally{
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 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)){
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);
assertContains(e.getMessage(), exceptionMessage);
return;
}
fail("Failed to see exception with message:"+exceptionMessage);
fail("Failed to see exception with message:" + exceptionMessage);
}
@Override
......@@ -302,11 +299,11 @@ public class TestMergeUsing extends TestBase implements Trigger {
throw new AssertionError("connection is null");
}
if (triggerName.startsWith("INS_BEFORE")) {
newRow[1] = newRow[1] + "-inserted"+(++triggerTestingUpdateCount);
newRow[1] = newRow[1] + "-inserted" + (++triggerTestingUpdateCount);
} else if (triggerName.startsWith("UPD_BEFORE")) {
newRow[1] = newRow[1] + "-updated"+(++triggerTestingUpdateCount);
newRow[1] = newRow[1] + "-updated" + (++triggerTestingUpdateCount);
} else if (triggerName.startsWith("DEL_BEFORE")) {
oldRow[1] = oldRow[1] + "-deleted"+(++triggerTestingUpdateCount);
oldRow[1] = oldRow[1] + "-deleted" + (++triggerTestingUpdateCount);
}
}
......@@ -327,30 +324,28 @@ public class TestMergeUsing extends TestBase implements 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.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);
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(){
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() + "\";");
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 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论