The
MERGE statement was introduced in Oracle 9i to conditionally insert or update data depending on its presence, a process also known as an "upsert". The MERGE statement reduces table scans and can perform the operation in parallel if required. With different releases of Oracle MERGE has also got enhancements.
Use the
MERGE statement to select rows from one or more sources for update or insertion into a table or view. You can specify conditions to determine whether to update or insert into the target table or view.
This statement is a convenient way to combine multiple operations. It lets you avoid multiple
INSERT, UPDATE, and DELETE DML statements.MERGE is a deterministic statement. You cannot update the same row of the target table multiple times in the same MERGE statement.
Oracle Database does not implement fine-grained access control during MERGE statements. If you are using the fine-grained access control feature on the target table or tables, then use equivalent INSERT and UPDATE statements instead of MERGE to avoid error messages and to ensure correct access control.
Prerequisite:
You must have the
INSERT and UPDATE object privileges on the target table and the SELECT object privilege on the source table. To specify the DELETE clause of the merge_update_clause, you must also have the DELETE object privilege on the target table.Syntax:

MERGE [ hint ]
INTO [ schema. ] { table | view } [ t_alias ]
USING { [ schema. ] { table | view }
| subquery
} [ t_alias ]
ON ( condition )
[ merge_update_clause ]
[ merge_insert_clause ]
[ error_logging_clause ] ;
merge_update_clause ::=

merge_insert_clause ::=
error_logging_clause ::=

LOG ERRORS
[ INTO [schema.] table ]
[ (simple_expression) ]
[ REJECT LIMIT { integer | UNLIMITED } ]
Initially when MERGE statement was introduced it has the following syntax:
Consider the following example where data from theHR_RECORDStable is merged into theEMPLOYEEStable.MERGE INTO employees e USING hr_records h ON (e.id = h.emp_id) WHEN MATCHED THEN UPDATE SET e.address = h.address WHEN NOT MATCHED THEN INSERT (id, address) VALUES (h.emp_id, h.address);
The source can also be a query.MERGE INTO employees e USING (SELECT * FROM hr_records WHERE start_date > ADD_MONTHS(SYSDATE, -1)) h ON (e.id = h.emp_id) WHEN MATCHED THEN UPDATE SET e.address = h.address WHEN NOT MATCHED THEN INSERT (id, address) VALUES (h.emp_id, h.address);
With further Oracle release there was a tremendous enhancement in the way MERGE works.
MERGE Statement Enhancements in Oracle Database 10g
We will be using a test table to explain the Enhancement with example.
CREATE TABLE test1 AS
SELECT *
FROM all_objects
WHERE 1=2;
1. Optional Clauses
Themerge_insert_clausespecifies values to insert into the column of the target table if the condition of theONclause is false. If the insert clause is executed, then all insert triggers defined on the target table are activated. If you omit the column list after theINSERTkeyword, then the number of columns in the target table must match the number of values in theVALUESclause.Themerge_update_clausespecifies the new column values of the target table. Oracle performs this update if the condition of theONclause is true. If the update clause is executed, then all update triggers defined on the target table are activated.In previous oracle version these two clauses were used together. From 10g theMATCHEDandNOT MATCHEDclauses are now optional ( can be used without other) making all of the following examples valid.-- Both clauses present. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN MATCHED THEN UPDATE SET a.status = b.status WHEN NOT MATCHED THEN INSERT (object_id, status) VALUES (b.object_id, b.status); -- No matched clause, insert only. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN NOT MATCHED THEN INSERT (object_id, status) VALUES (b.object_id, b.status); -- No not-matched clause, update only. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN MATCHED THEN UPDATE SET a.status = b.status;Conditional Operations
Conditional inserts and updates are now possible by using aWHEREclause on these statements.Specify thewhere_clauseif you want the database to execute the insert/update operation only if the specified condition is true. The condition can refer to either the data source or the target table. If the condition is not true, then the database skips the insert/update operation when merging the row into the table.-- Both clauses present. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN MATCHED THEN UPDATE SET a.status = b.status WHERE b.status != 'VALID' WHEN NOT MATCHED THEN INSERT (object_id, status) VALUES (b.object_id, b.status) WHERE b.status != 'VALID'; -- No matched clause, insert only. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN NOT MATCHED THEN INSERT (object_id, status) VALUES (b.object_id, b.status) WHERE b.status != 'VALID'; -- No not-matched clause, update only. MERGE INTO test1 a USING all_objects b ON (a.object_id = b.object_id) WHEN MATCHED THEN UPDATE SET a.status = b.status WHERE b.status != 'VALID';DELETE Clause
An optionalDELETE WHEREclause can be added to theMATCHEDclause to clean up after a merge operation. Only those rows in the destination table that match both theONclause and theDELETE WHEREare deleted. Depending on which table theDELETE WHEREreferences, it can target the rows prior or post update. The following examples clarify this.Create a source table with 5 rows as follows.CREATE TABLE source AS SELECT level AS id, CASE WHEN MOD(level, 2) = 0 THEN 10 ELSE 20 END AS status, 'Description of level ' || level AS description FROM dual CONNECT BY level <= 5; SELECT * FROM source; ID STATUS DESCRIPTION ---------- ---------- ----------------------- 1 20 Description of level 1 2 10 Description of level 2 3 20 Description of level 3 4 10 Description of level 4 5 20 Description of level 5 5 rows selected. SQL>Create the destination table using a similar query, but this time with 10 rows.CREATE TABLE destination AS SELECT level AS id, CASE WHEN MOD(level, 2) = 0 THEN 10 ELSE 20 END AS status, 'Description of level ' || level AS description FROM dual CONNECT BY level <= 10; SELECT * FROM destination; 1 20 Description of level 1 2 10 Description of level 2 3 20 Description of level 3 4 10 Description of level 4 5 20 Description of level 5 6 10 Description of level 6 7 20 Description of level 7 8 10 Description of level 8 9 20 Description of level 9 10 10 Description of level 10 10 rows selected. SQL>The followingMERGEstatement will update all the rows in the destination table that have a matching row in the source table. The additionalDELETE WHEREclause will delete only those rows that were matched, already in the destination table, and meet the criteria of theDELETE WHEREclause.MERGE INTO destination d USING source s ON (s.id = d.id) WHEN MATCHED THEN UPDATE SET d.description = 'Updated' DELETE WHERE d.status = 10; 5 rows merged. SQL> SELECT * FROM destination; ID STATUS DESCRIPTION ---------- ---------- ----------------------- 1 20 Updated 3 20 Updated 5 20 Updated 6 10 Description of level 6 7 20 Description of level 7 8 10 Description of level 8 9 20 Description of level 9 10 10 Description of level 10 8 rows selected. SQL>Notice there are rows with a status of "10" that were not deleted. This is because there was no match between the source and destination for these rows, so the delete was not applicable.The following example shows theDELETE WHEREcan be made to match against values of the rows before the update operation, not after. In this case, all matching rows have their status changed to "10", but theDELETE WHEREreferences the source data, so the status is checked against the source, not the updated values.ROLLBACK; MERGE INTO destination d USING source s ON (s.id = d.id) WHEN MATCHED THEN UPDATE SET d.description = 'Updated', d.status = 10 DELETE WHERE s.status = 10; 5 rows merged. SQL> SELECT * FROM destination; ID STATUS DESCRIPTION ---------- ---------- ----------------------- 1 10 Updated 3 10 Updated 5 10 Updated 6 10 Description of level 6 7 20 Description of level 7 8 10 Description of level 8 9 20 Description of level 9 10 10 Description of level 10 8 rows selected. SQL>Notice, no extra rows were deleted compared to the previous example.By switching the DELETE WHERE to reference the destination table, the extra updated rows can be deleted also.ROLLBACK; MERGE INTO destination d USING source s ON (s.id = d.id) WHEN MATCHED THEN UPDATE SET d.description = 'Updated', d.status = 10 DELETE WHERE d.status = 10; 5 rows merged. SQL> SELECT * FROM destination; ID STATUS DESCRIPTION ---------- ---------- ----------------------- 6 10 Description of level 6 7 20 Description of level 7 8 10 Description of level 8 9 20 Description of level 9 10 10 Description of level 10 5 rows selected. SQL>
Restrictions on the merge_update_clause
This clause is subject to the following restrictions:
- You cannot update a column that is referenced in the ON condition clause.
- You cannot specify DEFAULT when updating a view.
Restriction on Merging into a View
- You cannot specify
DEFAULTwhen updating a view.
Advantages of Using MERGE


0 comments:
Post a Comment