Selecting values while merging data
When you update existing data and insert new data in a single merge operation, you can select values from those rows at the same time.
Procedure
To select values from rows that are being merged:
- The value of an automatically generated column such as a ROWID or identity column
- Any default values for columns
- All values for a merged row, without specifying individual column names
- Calculated values based on the changes to merged rows
Example
| SYMBOL | PRICE |
|---|---|
| XCOM | 95.00 |
| YCOM | 24.50 |
| hv_symbol | hv_price |
|---|---|
| XCOM | 97.00 |
| NEWC | 30.00 |
| XCOM | 107.00 |
NEWC is new to the STOCK table, so its symbol and price need to be inserted into the STOCK table. The rows for XCOM in Table 2represent changed stock prices, so these values need to be updated in the STOCK table. Also, the output needs to show the change in stock prices as a DELTA value.
SELECT SYMBOL, PRICE, DELTA FROM FINAL TABLE
(MERGE INTO STOCK AS S INCLUDE (DELTA DECIMAL(5,20)
USING ((:hv_symbol, :hv_price) FOR :hv_nrows ROWS) AS R (SYMBOL, PRICE)
ON S.SYMBOL = R.SYMBOL
WHEN MATCHED THEN UPDATE SET
DELTA = R.PRICE - S.PRICE, PRICE=R.PRICE
WHEN NOT MATCHED THEN INSERT
(SYMBOL, PRICE, DELTA) VALUES (R.SYMBOL, R.PRICE, R.PRICE)
NOT ATOMIC CONTINUE ON SQLEXCEPTION);The INCLUDE clause specifies that an additional column, DELTA, can be returned in the output without adding a column to the STOCK table. The UPDATE portion of the MERGE statement sets the DELTA value to the differential of the previous stock price with the value set for the update operation. The INSERT portion of the MERGE statement sets the DELTA value to the same value as the PRICE column.
| SYMBOL | PRICE |
|---|---|
| XCOM | 107.00 |
| YCOM | 24.50 |
| NEWC | 30.00 |
SYMBOL PRICE DELTA
=============================
XCOM 97.00 2.00
NEWC 30.00 30.00
XCOM 107.00 10.00