Examples of MERGE
-
Update books when present, or add new record if absent
MERGE INTO books b USING purchases p ON p.title = b.title and p.type = 'bk' WHEN MATCHED THEN UPDATE SET b.desc = b.desc || '; ' || p.desc WHEN NOT MATCHED THEN INSERT (title, desc, bought) values (p.title, p.desc, p.bought);
-
Using a derived table
MERGE INTO customers c USING (SELECT * from customers_delta WHERE id > 10) cd ON (c.id = cd.id) WHEN MATCHED THEN UPDATE SET name = cd.name WHEN NOT MATCHED THEN INSERT (id, name) values (cd.id, cd.name);
-
Together with a recursive CTE
MERGE INTO numbers USING ( WITH RECURSIVE r(n) AS ( SELECT 1 FROM rdb$database UNION ALL SELECT n+1 FROM r WHERE n < 200 ) SELECT n FROM r ) t ON numbers.num = t.n WHEN NOT MATCHED THEN INSERT(num) VALUES(t.n);
-
Using
DELETE
clauseMERGE INTO SALARY_HISTORY USING ( SELECT EMP_NO FROM EMPLOYEE WHERE DEPT_NO = 120) EMP ON SALARY_HISTORY.EMP_NO = EMP.EMP_NO WHEN MATCHED THEN DELETE
-
The following example updates the
PRODUCT_INVENTORY
table daily based on orders processed in theSALES_ORDER_LINE
table.If the stock level of the product would drop to zero or lower, then the row for that product is removed from thePRODUCT_INVENTORY
table.MERGE INTO PRODUCT_INVENTORY AS TARGET USING ( SELECT SL.ID_PRODUCT, SUM (SL.QUANTITY) FROM SALES_ORDER_LINE SL JOIN SALES_ORDER S ON S.ID = SL.ID_SALES_ORDER WHERE S.BYDATE = CURRENT_DATE GROUP BY 1 ) AS SRC (ID_PRODUCT, QUANTITY) ON TARGET.ID_PRODUCT = SRC.ID_PRODUCT WHEN MATCHED AND TARGET.QUANTITY - SRC.QUANTITY <= 0 THEN DELETE WHEN MATCHED THEN UPDATE SET TARGET.QUANTITY = TARGET.QUANTITY - SRC.QUANTITY, TARGET.BYDATE = CURRENT_DATE