CREATE VIEW ALLTRANS AS SELECT ITEM, TRNTP, DATE, QTY FROM TRAN1999
UNION SELECT ITEM, TRNTP, DATE, QTY FROM TRAN2000
UNION SELECT ITEM, TRNTP, DATE, QTY FROM TRAN2001 |
|
Figure 3: The UNION clause can now be used within an SQL VIEW.
This example selects records from the files TRAN1999, TRAN2000, and TRAN2001. The resulting VIEW would display records from each of these tables within a single results set. So rather than reading all the records from TRAN1999, then all the records from TRAN2000, and finally all the records from TRAN2001, you can simply read all of the data from the VIEW ALLTRANS.
Also available in V5R2 of DB2 UDB is the IDENTITY column attribute. IDENTITY allows you to create a field as an auto-incrementing field. For each record created, this value will increment, which is useful anywhere you need a "next-up" number (order numbers, customer numbers, etc.). Figure 4 shows an example of how the IDENTITY column attribute would be used.
CREATE TABLE Orders( Ordno INTEGER GENERATED ALWAYS AS IDENTITY (START WITH 100, INCREMENT BY 1), Cust AS CHAR(10), Item AS CHAR(10), Qty AS INTEGER ) |
|
Figure 4: IDENTITY columns are auto-incrementing numeric fields.
It's important to note that, while an IDENTITY will automatically increment each time a record is created, this value can be overridden on an INSERT or UPDATE statement if the OVERRIDE clause is used. As a result, the value of the IDENTITY column cannot be guaranteed to be unique unless it is used as part of the primary key or a unique index.
Another addition to V5R2 is the ROWID column. This column can be used to navigate to any row within any table directly. The ROWID value is kept unique even across multiple tables. This 40-byte field contains a unique identifier for each row in each table within your database.
The GLOBAL TEMPORARY TABLE statement is used to create a temporary table that is not registered in the system catalog. The table created can't be processes outside of the one that created it and is automatically deleted when the application ends. GLOBAL TEMPORARY TABLEs are always created in the SESSION schema, which on the iSeries is actually QTEMP library. When combined with the LIKE clause discussed earlier, this statement can be a great help in creating work files within an SQL procedure. Figure 5 contains an example of how this statement is used.
DECLARE GLOBAL TEMPORARY TABLE summary LIKE sales_summ ON COMMIT DELETE ROWS |
|
Figure 5: GLOBAL TEMPORARY TABLE can be used for work file creation.
This example will create a temporary table named summary using the same format as the table named sales_summ. When the process that executed this statement is completed, the table will be removed. While the process is active, the temporary table won't be visible to any other applications.
Additions to DB2 UDB for iSeries SQL procedure language--which is used for stored procedures, triggers, and functions--include the ability to use nested compound statements. This means that you can now create multiple levels of BEGIN/END groups within one another. Figure 6 contains an example of how this would look in a stored procedure.
CREATE PROCEDURE CheckCategory... BEGIN DECLARE CONTINUE HANDLER FOR SQLEXCEPTION BEGIN SET PrevSQLState=SQLSTATE; SET ErrorState=ErrorOccurred; END; ,,, SET ErrorState=CleanState; SET MyCategory=SELECT Category FROM orders WHERE... ... BEGIN DECLARE CONTINUE HANDLER FOR SQLEXCEPTION... UPDATE inquiries SET inqCount=inqCount+1 WHERE MyCat... END; |
|
Figure 6: Stored Procedures now support nested compound statements.
In addition to nested compound statements, the iSeries SQL procedure language now supports the ITERATE statement, which allows you to skip to the next iteration of a LOOP/END LOOP group. Figure 7 gives an example of this function.
loopa: LOOP FETCH crsr INTO orddate, amount; IF orddate ITERATE loopa; END IF; INSERT INTO neworders VALUES(orddate, amount); END LOOP; |
|
Figure 7: The ITERATE statement is used with a LOOP/END LOOP group.
In this example, on each pass through the loop, a record will be read from the cursor crsr. If the value of the field orddate is less than the field startdate, the ITERATE statement is executed to send control back to the start of the loop. Otherwise, the data read is added to the table neworders using the INSERT INTO statement.
Additional enhancements to stored procedure functions include SAVEPOIINTS. This is a means by which a stored procedure can create "bookmarks" within a transaction set. SAVEPOINTS are used along with the ROLLBACK TO statement to allow a stored procedure to roll the transactions back to a specified point. Figure 8 shows an example of the SAVEPOINTS statement.
loopa: LOOP FETCH crsr INTO orddate, amount; IF SQLCODE<0 THEN ROLLBACK TO SAVEPOINT svpt1; ELSE RELEASE svpt1; END IF; IF orddate |
|
Figure 8: SAVEPOINTS allow transactions to be rolled back to a specified point.
In this example, if the SQLCODE value is less than 0, the transactions are rolled back to the previous SAVEPOINT. If not, the SAVEPOINT is released and processing continues. After the execution of the INSERT INTO statement, a new SAVEPOINT is created. DB2 UDB starts new SAVEPOINTS for each function or trigger. You also have the option of starting a new SAVEPOINT level from a procedure. This option is controlled through the use of the OLD SAVEPOINT LEVEL and NEW SAVEPOINT LEVEL statements. If OLD SAVEPOINT LEVEL is specified, a new SAVEPOINT level is not created. If NEW SAVEPOINT LEVEL is used, a new SAVEPOINT level will be created when the procedure is started. The SAVEPOINT names defined are local to the current SAVEPOINT level. Because SAVEPOINTS allow you to roll back transactions to a specific point, the transaction recovery is faster. SAVEPOINTS remain active until a COMMIT, RELEASE, ROLLBACK, or ROLLBACK TO statement is received. The COMMIT ON RETURN option allows you to define whether or a COMMIT should be issued automatically on return from a procedure. Valid values for this option are YES to commit transactions if the procedure successfully returns and NO, which causes no COMMIT.
SQL User Defined Table Functions (UDTF) allow you to create an SQL function that returns a result set. The UDTF can be used anywhere that you would normally use a table. This includes using them as part of view. Figure 9 shows a sample of a User-defined Table Function.
CREATE FUNCTION CustomerSales(Custno CHAR(10)) RETURN TABLE(Item CHAR(15), Perd INT(8), Units INT(10), Sales DEC(15,2)) LANGUAGE SQL RETURN SELECT Item, Perd, Units, Sales FROM SALESHST WHERE SALESHIST.CUST = CustomerSales.Custno |
|
Figure 9: This User Defined Table Function returns sales data.
In this example, the function accepts the field CUSTNO as its only parameter. The results set returned contains data for all values matching the supplied parameter. The following SELECT statement is an example of how you would use this function:
SELECT * FROM CustomerSales('CUS12345');
When this command is executed, the result set returned will contain all records from the SALESHIST table where the CUST field matches the value supplied in the CUSTNO parameter.
UDTFs can also be used with external functions. One important difference when using an external UDTF is that these functions will return only one row at a time. DB2 UDB will internally call the external UDTF multiple times to return subsequent records. External UDTFs support all programs supported by SQL user defined functions. Figure 10 shows an example of how an external UDTF would be defined.
CREATE FUNCTION DOCMATCH (VARCHAR(30), VARCHAR(255)) RETURNS TABLE (DOCID CHAR(16)) EXTERNAL NAME 'MYLIB/RAJIV(UDFMATCH)' LANGUAGE C PARAMETER STYLE DB2SQL NO SQL DETERMINISTIC CARDINALITY 20 |
|
Figure 10: External UDTFs use iSeries programs to return data to SQL.
In this example, the DETERMINISTIC option tells DB2 UDB that on subsequent calls using the same parameters, the same data will be returned. The CARDINALITY option is used to define the estimated number of rows that will be returned by the function. This parameter is valid for both external UDTFs and SQL UDTFs.
Scalar Subselect functionality has also been extended to allow a subselect statement to be used anywhere that an expression can be used. This includes being able to use a subselect within the INSERT INTO statement's VALUES clause. Figure 11 shows an example of how a subselect might be used.
SELECT Custno, Cusnam, (SELECT MAX(Orddat) FROM OrdrHdr WHERE OrdrHdr.Custno = CustMast.Custno) AS LastOrd FROM CustMast |
|
Figure 11: This subselect is used to select the last order date by customer.
In this example, you select the MAX(Orddat) to get the last order date for the current customer. The results would be a customer listing with last order date information.
In another example of IBM's efforts to extend existing SQL functionality in V5R2, ORDER BY clause restrictions have been removed. Prior to this, only fields that were specified in the SELECT list could be included as part of the ORDER BY clause. In V5R2, you'll be able to specify any field in your source tables as part of the ORDER BY clause, regardless of whether or not those tables appear as part of your SELECT list. Figure 12 shows an example of a statement that will be allowed in V5R2 that would not have been allowed in prior releases.
SELECT CUSNAM, CUSADD, CUSCTY, CUSSTE, CUSZIP FROM CUSTMAST ORDER BY CUSNO |
|
Figure 12: The ORDER BY clause is more flexible in V5R2.
In this example, you select the name and address fields from the customer master file and sort the output by the customer number field.
ODBC and JDBC
The additions to the SQL functionality within V5R2 of DB2 UDB for iSeries are only part of the story. There are also several enhancements to the JDBC and ODBC functions. Commonly used SQL catalog views and tables will be available in V5R2, including those listed in Figure 13.
SQLCOLPRIVILEGES & SQLTABLEPRIVILEGES SQLCOLUMNS SQLFOREIGNKEYS & SQLPRIMARYKEYS SQLPROCEDURES & SQLPROCEDURECOLS SQLSCHEMAS SQLTABLES SQLSPECIALCOLUMNS SQLSTATISTICS SQLTYPEINFO & SQLUDTS |
|
Figure 13: New SQL catalog tables and views in V5R2.
All of the views will now exist in the SYSIBM library to conform to other ports of DB2 UDB. In addition, enhancements to JDBC include support for JDBC Version 3.0. These enhancements include support for SAVEPOINTS and multiple concurrently open stored procedure result sets. Also added is support for connections and statements pooling within the JDBC Datasource classes. The Java Transaction API (JTA) is now available with full support for the X/Open XA protocol.
ODBC enhancements abound as well, including support for large objects (LOBs) up to 2 GB. The current limit is 15 MB. There are two new ODBC drivers available, one for the 64-bit version of the Windows operating system and the other for Linux clients. Support for the SQLTablePrivileges and SQLColPrivileges views has also been extended. These two functions allow you to define a user's rights to a given table or column within a table.
Software Updates
In addition to all of the changes mentioned so far, there are also updates to some of the software components related to DB2 UDB for iSeries. To start, the DB2 OLAP Miner has been added to DB2 OLAP Server 7.1. This utility adds data mining capabilities to the existing OLAP tool. It uses sophisticated algorithms called "deviation detection" to identify slices within OLAP cube data that deviate from the norm. These values can then be used to drive your OLAP analysis, giving you a more pinpointed way to analyze your OLAP data.
Data migration toolkits have been added as well, including the Oracle Migration Toolkit, which converts data from Oracle into DB2 UDB for iSeries.
Support for integration with the iSeries Linux operating system is also available, including support for connecting to DB2 UDB for iSeries from the Linux LPAR via DB2 Connect software, ODBC, and JDBC.
I hope this has helped to pique your anticipation for the V5R2 version of DB2 UDB for iSeries. For more information, check out the DB2 UDB for iSeries Web site.
Special thanks to Kent Milligan from the DB2 UDB for iSeries Technology Team for helping me get the scoop on what's new in V5R2 for DB2 so that I could share it with you.
Mike Faust is the MIS Manager for The Lehigh Group in Macungie, PA. Mike has nearly 15 years of experience with midrange computers and personal computers. Check out Mike's book "The iSeries & AS/400 Programmer's Guide to Cool Things" available from MC Press.
LATEST COMMENTS
MC Press Online