Tuesday, April 10, 2007

MERGE and TRUNCATE [DB2 9 for z/OS]

Two additional new SQL statements available in DB2 Version 9 are the MERGE and TRUNCATE statements.

MERGE

The MERGE statement basically takes two “tables” and merges the data into one table. The table that will contain the merged results is referred to as the target; the other participating table is called the source. Rows in the target that match the source are updated and rows that do not exist in the target are inserted from the source to the target.

If you use other DBMSs you may be somewhat familiar with MERGE functionality. It is sometimes called an UPSERT (taking the UP from update and the SERT from insert). A simplified version of the MERGE syntax follows:


MERGE INTO table_name
USING table_name
ON (condition)
WHEN MATCHED THEN
UPDATE SET column1 = value1 [, column2 = value2 ...]
WHEN NOT MATCHED
THEN INSERT column1 [, column2 ...]
VALUES (value1 [, value2 ...]) ;



The DB2 implementation is a tad different, though. Instead of the USING clause specifying an actual table, it instead specifies a VALUES clause of data for a single row or an array of rows. So the source, if it consists of multiple rows, must be populated into a host variable array.

So, say we have a customer table, CUST, and we want to accept several customers from a file. If the customer already exists, we want to populate it with the new, updated information; if the customer does not exist, we want to insert the new customer. To accomplish this in DB2 V9, we can write a MERGE statement such as this:


MERGE INTO CUST C
USING VALUES
((:CUSTNO, :CUSTNAME, :CUSTDESC)
FOR :HV_NROWS ROWS) AS N (CUSTNO, NAME, DESC)
ON (C.CUSTNO = N.CUSTNO)
WHEN MATCHED THEN UPDATE
SET (C.NAME, C.DESC) = (N.NAME, N.DESC)
WHEN NOT MATCHED THEN INSERT (CUSTNO, NAME, DESC)
VALUES (N.CUSTNO, N.NAME, N.DESC)
NOT ATOMIC CONTINUE ON SQL EXCEPTION;



Of course, this is a simple example as there will likely be many other columns in the customer table that would be of interest. But you can easily extrapolate from this example using it as a template of sorts to build a more complex example.

The rows of input data are processed separately. When errors are encountered and NOT ATOMIC CONTINUE ON SQL EXCEPTION is in effect, processing continues, and some of the specified rows will not be processed. Regardless of the failure of any particular source row, the MERGE statement will not undo any changes that are made to the database by the statement. Merge will be attempted for rows that follow the failed row. However, the minimum level of atomicity is at least that of a single source row (in other words, it is not possible for a partial merge to complete).

If you are using triggers be sure to consult the SQL Reference manual (PDF) to understand how MERGE impacts trigger processing.

At any rate, you need to know that the MERGE statement lets you combine UPDATE and INSERT across many rows into a table based upon a matching key. You can embed the MERGE statement in an application program or issue it interactively. The statement is executable and can be dynamically prepared. In addition, you can use the SELECT FROM MERGE statement to return all the updated rows and inserted rows, including column values that are generated by DB2.

TRUNCATE

OK, so that is MERGE, but the title of this blog entry is MERGE and TRUNCATE, so what is TRUNCATE? Well, that is an easier story to tell. The TRUNCATE statement is simply a quick way to DELETE all of the data from a table. The table can be in any type of table space and it can be either a base table or a declared global temporary table. If the table contains LOB or XML columns, the corresponding table spaces and indexes are also truncated.

For clarification, consider the following example:



TRUNCATE TABLE EXAMPLE_TABLE
REUSE STORAGE
IGNORE DELETE TRIGGERS
IMMEDIATE;



Seems easy enough, doesn’t it? But what are those additional parameters? Well, REUSE STORAGE tells DB2 to empty the storage that is allocated but keeps it allocated. The alternate, which is the default, is DROP STORAGE. This option tells DB2 to release the storage that is allocated for the table and to make it available for use for the same table or any other table in the table space. REUSE STORAGE is ignored for a table in a simple table space and the statement is processed as if DROP STORAGE is specified.

The next parameter, which is the default if nothing is specified, is IGNORE DELETE TRIGGERS. This tells DB2 to not fire any DELETE triggers. Alternately, you could specify RESTRICT WHEN DELETE TRIGGERS, which will return an error if there are any delete triggers defined on the table.

Finally, we have the IMMEDIATE option. This causes the TRUNCATE to be immediately executed and it cannot be undone. If IMMEDIATE is not specified you can issue a ROLLBACK to undo the TRUNCATE.

Synopsis

So with DB2 9 for z/OS we have two new helpful SQL statements that can simplify our coding efforts. MERGE to combine INSERT and UPDATE processing and TRUNCATE to quickly DELETE all data from a table. Keep them in mind and use them to aid your DB2 application development efforts.

8 comments:

Anonymous said...

Do you know if Truncate creates a valid recovery point?

Craig S. Mullins said...

By default, a ROLLBACK statement can undo the truncate operation. However, if you specify
IMMEDIATE, the truncate operation is processed immediately and cannot be undone.

Anonymous said...

No, what I am really trying to ask is if you use the truncate, does that become a valid point of forward recovery or do I have to image copy the empty table to do a recovery from that point forward?

Anonymous said...

I am trying to use "NOT ATOMIC CONTINUE ON SQL EXCEPTION" in the Windows Version of DB2 and getting a error. is this specific to only Z/OS version, because I do not find it in any other versions

Anonymous said...

Hi,
I can't get a single row merge to work from a COBOL program on the mainframe; I get a -158 for the bind (precompile is fine).
My sql looks like:
EXEC SQL
MERGE INTO New_Table AS NT
USING ( VALUES VALUE-SINGLE-ROW
(:WS-KEY
,:WS-ITEM-NBR) ) AS TT
(TABLE_KEY, ITEM_NBR)
ON (NT.TABLE_KEY = TT.TABLE_KEY)
WHEN MATCHED THEN UPDATE
SET NT.ITEM_NBR = TT.ITEM_NBR
WHEN NOT MATCHED THEN INSERT
(TABLE_KEY, ITEM_NBR)
VALUES
(TT.TABLE_KEY, TT.ITEM_NBR)
END-EXEC
What am I doing wrong? Thanks!

Anonymous said...

Hi Craig,

I am working on db2 Zos.

Merge is working with values clause but I am getting -199 when I use select as a source table.

Pl let me know if select also works in merge.

If so, Please give me a simple example.

Anton Larson said...

Thanks!

Anonymous said...

thanks for share.