-
Notifications
You must be signed in to change notification settings - Fork 34
Add Oracle UPSERT #645
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
base: develop
Are you sure you want to change the base?
Add Oracle UPSERT #645
Changes from all commits
5ea49a5
8dd0a70
ff99420
7af87d7
baddfe4
94a67f0
9889627
133bbf9
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,122 @@ | ||
| /* | ||
| * Copyright © 2026 Cask Data, Inc. | ||
| * | ||
| * Licensed under the Apache License, Version 2.0 (the "License"); you may not | ||
| * use this file except in compliance with the License. You may obtain a copy of | ||
| * the License at | ||
| * | ||
| * http://www.apache.org/licenses/LICENSE-2.0 | ||
| * | ||
| * Unless required by applicable law or agreed to in writing, software | ||
| * distributed under the License is distributed on an "AS IS" BASIS, WITHOUT | ||
| * WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the | ||
| * License for the specific language governing permissions and limitations under | ||
| * the License. | ||
| */ | ||
|
|
||
| package io.cdap.plugin.oracle; | ||
|
|
||
| import io.cdap.plugin.db.sink.ETLDBOutputFormat; | ||
|
|
||
| /** | ||
| * Class that extends {@link ETLDBOutputFormat} to implement the abstract methods | ||
| */ | ||
| public class OracleETLDBOutputFormat extends ETLDBOutputFormat { | ||
|
|
||
| /** | ||
| * This method is used to construct the upsert query for Oracle using MERGE statement. | ||
| * Example - MERGE INTO my_table target | ||
| * USING (SELECT ? AS id, ? AS name, ? AS age FROM dual) source | ||
| * ON (target.id = source.id) | ||
| * WHEN MATCHED THEN UPDATE SET target.name = source.name, target.age = source.age | ||
| * WHEN NOT MATCHED THEN INSERT (id, name, age) VALUES (source.id, source.name, source.age) | ||
| * @param table - Name of the table | ||
| * @param fieldNames - All the columns of the table | ||
| * @param listKeys - The columns used as keys for matching | ||
| * @return Upsert query in the form of string | ||
| */ | ||
| @Override | ||
| public String constructUpsertQuery(String table, String[] fieldNames, String[] listKeys) { | ||
| if (listKeys == null) { | ||
| throw new IllegalArgumentException("Column names to be updated should not be null"); | ||
| } else if (fieldNames == null) { | ||
| throw new IllegalArgumentException("Field names should not be null"); | ||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. similar comment here. Better to move these to sink config validations to fail early. |
||
| } else { | ||
| StringBuilder query = new StringBuilder(); | ||
|
|
||
| // MERGE INTO target_table target | ||
| query.append("MERGE INTO ").append(table).append(" target "); | ||
|
|
||
| // USING (SELECT ? AS col1, ? AS col2, ... FROM dual) source | ||
| query.append("USING (SELECT "); | ||
| for (int i = 0; i < fieldNames.length; ++i) { | ||
| query.append("? AS ").append(fieldNames[i]); | ||
| if (i != fieldNames.length - 1) { | ||
| query.append(", "); | ||
| } | ||
| } | ||
| query.append(" FROM dual) source "); | ||
|
|
||
| // ON (target.key1 = source.key1 AND target.key2 = source.key2 ...) | ||
| query.append("ON ("); | ||
| for (int i = 0; i < listKeys.length; ++i) { | ||
| query.append("target.").append(listKeys[i]).append(" = source.").append(listKeys[i]); | ||
| if (i != listKeys.length - 1) { | ||
| query.append(" AND "); | ||
| } | ||
| } | ||
| query.append(") "); | ||
|
|
||
| // WHEN MATCHED THEN UPDATE SET target.col1 = source.col1, target.col2 = source.col2 ... | ||
| // Only update non-key columns | ||
| query.append("WHEN MATCHED THEN UPDATE SET "); | ||
| boolean firstUpdateColumn = true; | ||
| for (String fieldName : fieldNames) { | ||
| boolean isKeyColumn = false; | ||
| for (String listKey : listKeys) { | ||
| String listKeyNoQuote = listKey.replace("\"", ""); | ||
| if (listKeyNoQuote.equals(fieldName)) { | ||
| isKeyColumn = true; | ||
| break; | ||
| } | ||
| } | ||
| if (!isKeyColumn) { | ||
| if (!firstUpdateColumn) { | ||
| query.append(", "); | ||
| } | ||
| query.append("target.").append(fieldName).append(" = source.").append(fieldName); | ||
| firstUpdateColumn = false; | ||
| } | ||
| } | ||
|
|
||
| // WHEN NOT MATCHED THEN INSERT (col1, col2, ...) VALUES (source.col1, source.col2, ...) | ||
| query.append(" WHEN NOT MATCHED THEN INSERT ("); | ||
| for (int i = 0; i < fieldNames.length; ++i) { | ||
| query.append(fieldNames[i]); | ||
| if (i != fieldNames.length - 1) { | ||
| query.append(", "); | ||
| } | ||
| } | ||
| query.append(") VALUES ("); | ||
| for (int i = 0; i < fieldNames.length; ++i) { | ||
| query.append("source.").append(fieldNames[i]); | ||
| if (i != fieldNames.length - 1) { | ||
| query.append(", "); | ||
| } | ||
| } | ||
| query.append(")"); | ||
|
|
||
| return query.toString(); | ||
| } | ||
| } | ||
|
|
||
| @Override | ||
| public String constructUpdateQuery(String table, String[] fieldNames, String[] listKeys) { | ||
| // Oracle JDBC does not accept a trailing semicolon in prepared statements. | ||
| String query = super.constructUpdateQuery(table, fieldNames, listKeys); | ||
| if (query.endsWith(";")) { | ||
| return query.substring(0, query.length() - 1); | ||
| } | ||
| return query; | ||
| } | ||
| } | ||
| Original file line number | Diff line number | Diff line change | ||
|---|---|---|---|---|
|
|
@@ -116,8 +116,15 @@ protected void handleField(ResultSet resultSet, StructuredRecord.Builder recordB | |||
| @Override | ||||
| protected void writeNonNullToDB(PreparedStatement stmt, Schema fieldSchema, | ||||
| String fieldName, int fieldIndex) throws SQLException { | ||||
| int sqlType = columnTypes.get(fieldIndex).getType(); | ||||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. In which case, is it possible that |
||||
| int sqlIndex = fieldIndex + 1; | ||||
| int sqlType = Types.OTHER; | ||||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. should we be throwing an error if none of the Why are we assuming |
||||
| // avoid OOB exception in case of mismatch between columnTypes and record schema fields | ||||
| for (ColumnType columnType : columnTypes) { | ||||
| if (columnType.getName().equals(fieldName)) { | ||||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. should we be using database-plugins/oracle-plugin/src/main/java/io/cdap/plugin/oracle/OracleSinkDBRecord.java Line 49 in ec0383c
|
||||
| sqlType = columnType.getType(); | ||||
| break; | ||||
| } | ||||
| } | ||||
|
|
||||
| // TIMESTAMP and TIMESTAMPTZ types needs to be handled using the specific oracle types to ensure that the data | ||||
| // inserted matches with the provided value. As Oracle driver internally alters the values provided | ||||
|
|
||||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,129 @@ | ||
| /* | ||
| * Copyright © 2026 Cask Data, Inc. | ||
| * | ||
| * Licensed under the Apache License, Version 2.0 (the "License"); you may not | ||
| * use this file except in compliance with the License. You may obtain a copy of | ||
| * the License at | ||
| * | ||
| * http://www.apache.org/licenses/LICENSE-2.0 | ||
| * | ||
| * Unless required by applicable law or agreed to in writing, software | ||
| * distributed under the License is distributed on an "AS IS" BASIS, WITHOUT | ||
| * WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the | ||
| * License for the specific language governing permissions and limitations under | ||
| * the License. | ||
| */ | ||
|
|
||
| package io.cdap.plugin.oracle; | ||
|
|
||
| import org.junit.Assert; | ||
| import org.junit.Test; | ||
|
|
||
| public class OracleETLDBOutputFormatTest { | ||
|
|
||
| private final OracleETLDBOutputFormat outputFormat = new OracleETLDBOutputFormat(); | ||
|
|
||
| @Test | ||
| public void testConstructUpsertQueryBasic() { | ||
| String[] fieldNames = {"id", "name", "age"}; | ||
| String[] listKeys = {"id"}; | ||
| String table = "my_table"; | ||
|
|
||
| String result = outputFormat.constructUpsertQuery(table, fieldNames, listKeys); | ||
|
|
||
| String expected = "MERGE INTO my_table target " + | ||
| "USING (SELECT ? AS id, ? AS name, ? AS age FROM dual) source " + | ||
| "ON (target.id = source.id) " + | ||
| "WHEN MATCHED THEN UPDATE SET target.name = source.name, target.age = source.age " + | ||
| "WHEN NOT MATCHED THEN INSERT (id, name, age) VALUES (source.id, source.name, source.age)"; | ||
|
|
||
| Assert.assertEquals(expected, result); | ||
| } | ||
|
|
||
| @Test | ||
| public void testConstructUpsertQueryMultipleKeys() { | ||
| String[] fieldNames = {"id", "code", "name", "value"}; | ||
| String[] listKeys = {"id", "code"}; | ||
| String table = "composite_key_table"; | ||
|
|
||
| String result = outputFormat.constructUpsertQuery(table, fieldNames, listKeys); | ||
|
|
||
| String expected = "MERGE INTO composite_key_table target " | ||
| + "USING (SELECT ? AS id, ? AS code, ? AS name, ? AS value FROM dual) source " | ||
| + "ON (target.id = source.id AND target.code = source.code) " | ||
| + "WHEN MATCHED THEN UPDATE SET target.name = source.name, target.value = source.value " | ||
| + "WHEN NOT MATCHED THEN INSERT (id, code, name, value) VALUES (source.id, source.code, source.name, source" | ||
| + ".value)"; | ||
|
|
||
| Assert.assertEquals(expected, result); | ||
| } | ||
|
|
||
| @Test | ||
| public void testConstructUpsertQuerySingleField() { | ||
| String[] fieldNames = {"id", "name"}; | ||
| String[] listKeys = {"id"}; | ||
| String table = "single_field_update_table"; | ||
|
|
||
| String result = outputFormat.constructUpsertQuery(table, fieldNames, listKeys); | ||
|
|
||
| String expected = "MERGE INTO single_field_update_table target " + | ||
| "USING (SELECT ? AS id, ? AS name FROM dual) source " + | ||
| "ON (target.id = source.id) " + | ||
| "WHEN MATCHED THEN UPDATE SET target.name = source.name " + | ||
| "WHEN NOT MATCHED THEN INSERT (id, name) VALUES (source.id, source.name)"; | ||
|
|
||
| Assert.assertEquals(expected, result); | ||
| } | ||
|
|
||
| @Test(expected = IllegalArgumentException.class) | ||
| public void testConstructUpsertQueryNullListKeys() { | ||
| String[] fieldNames = {"id", "name", "age"}; | ||
| String table = "my_table"; | ||
|
|
||
| outputFormat.constructUpsertQuery(table, fieldNames, null); | ||
| } | ||
|
|
||
| @Test(expected = IllegalArgumentException.class) | ||
| public void testConstructUpsertQueryNullFieldNames() { | ||
| String[] listKeys = {"id"}; | ||
| String table = "my_table"; | ||
|
|
||
| outputFormat.constructUpsertQuery(table, null, listKeys); | ||
| } | ||
|
|
||
| @Test | ||
| public void testConstructUpsertQueryAllFieldsAreKeys() { | ||
| String[] fieldNames = {"id", "code"}; | ||
| String[] listKeys = {"id", "code"}; | ||
| String table = "all_keys_table"; | ||
|
|
||
| String result = outputFormat.constructUpsertQuery(table, fieldNames, listKeys); | ||
|
|
||
| // When all fields are keys, the UPDATE SET clause will be empty after "SET " | ||
| // Note: There's an extra space before "WHEN NOT MATCHED" due to implementation | ||
| String expected = "MERGE INTO all_keys_table target " + | ||
| "USING (SELECT ? AS id, ? AS code FROM dual) source " + | ||
| "ON (target.id = source.id AND target.code = source.code) " + | ||
| "WHEN MATCHED THEN UPDATE SET " + | ||
| "WHEN NOT MATCHED THEN INSERT (id, code) VALUES (source.id, source.code)"; | ||
|
|
||
| Assert.assertEquals(expected, result); | ||
| } | ||
|
|
||
| @Test | ||
| public void testConstructUpsertQueryWithSpecialTableName() { | ||
| String[] fieldNames = {"id", "name"}; | ||
| String[] listKeys = {"id"}; | ||
| String table = "SCHEMA.MY_TABLE"; | ||
|
|
||
| String result = outputFormat.constructUpsertQuery(table, fieldNames, listKeys); | ||
|
|
||
| String expected = "MERGE INTO SCHEMA.MY_TABLE target " + | ||
| "USING (SELECT ? AS id, ? AS name FROM dual) source " + | ||
| "ON (target.id = source.id) " + | ||
| "WHEN MATCHED THEN UPDATE SET target.name = source.name " + | ||
| "WHEN NOT MATCHED THEN INSERT (id, name) VALUES (source.id, source.name)"; | ||
|
|
||
| Assert.assertEquals(expected, result); | ||
| } | ||
| } |
Uh oh!
There was an error while loading. Please reload this page.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
what is the name for this config in UI?
Column namesdoes not help understand which config are we exactly talking about.Also, can we move these to sink config validations when
UPSERTis selected?