@@ -78,8 +78,64 @@ public class TestMergeUsing extends TestBase {
"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
);
// Duplicate source keys: SQL standard says duplicate or repeated updates in same statement should cause errors
// One insert, one update one delete happens, 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,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 AS NAME FROM SYSTEM_RANGE(1,1)",
3,
"Unique index or primary key violation: \"Merge using ON column expression, duplicates values found:keys[ID]:values:[1]:from:PUBLIC.SOURCE:alias:SOURCE:current row number:2:conflicting row number:1"
);
}
/**
* 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