New capabilities allow designers and programmers to continue to produce new and exciting applications.
Because DB2 for i5/OS is embedded within i5/OS, application designers and programmers likely expected that with the V6R1 release of i5/OS there would be plenty of database enhancements included. They weren't disappointed, because the developers of DB2 for i5/OS have been busy developing many new functions and enhancements that should be of interest to anyone that works with the database. (Isn't that everyone?)
I certainly will not be able to cover all the new functions and enhancements. Nor will I be able to describe any in full detail. As a way to discuss this lineup of new functions and enhancements, they will be broken up into several categories. These will include SQL syntax, new catalog statistic views, application development, SQL Query Engine (SQE) and performance, increased limits, and the System i Navigator database tools.
Starting Off with the SQL Syntax
Query users will find the VALUES clause helpful when they want to add literals or variable values to their result set without creating another table first.
SELECT VAL1, VAL2,
WEEK(SALES_DATE) AS WEEK,
DAYOFWEEK(SALES_DATE) AS DAY_WEEK,
MONTH(SALES_DATE) AS MONTH,
REGION,
SALES AS UNITS_SOLD
FROM PRODAPPL.SALES,
(VALUES('GROUP 1','GROUP 2') ) AS X (VAL1,VAL2)
Also, this release brings true full outer join support, which is useful for joining tables where some rows from the joined tables may not have any rows.
The ORDER BY and the FETCH FIRST n ROWS ONLY clauses will now be allowed on any subselect. For example, if an application needs to union tables together but only wants the top 10 sales from different regions tables, this support makes this possible, as shown below:
(SELECT * FROM PRODAPPL.SALES_EAST
ORDER BY SALES DESC FETCH FIRST 10 ROWS ONLY)
UNION ALL
(SELECT * FROM PRODAPPL.SALES_CENT
ORDER BY SALES DESC FETCH FIRST 10 ROWS ONLY)
UNION ALL
(SELECT * FROM PRODAPPL.SALES_WEST
ORDER BY SALES DESC FETCH FIRST 10 ROWS ONLY)
Another nice query enhancement is the INSERT in the FROM clause. This will help with cases where the value is generated by DB2 for i5/OS. It allows the programmer to access the result rows of the INSERT statement as part of the SELECT statement.
SELECT *
FROM FINAL TABLE ( INSERT INTO PRODAPPL.SALES_COPY ( SALES_DATE,
SALES_PERSON, REGION, SALES )
SELECT * FROM PRODAPPL.SALES )
ORDER BY INPUT SEQUENCE;
In addition, grouping sets and super groups were introduced, which allows the programmer to do multiple groupings and include the groups in the final result set. In prior releases, there was no way to do this except to run multiple queries.
SELECT WEEK(SALES_DATE) AS WEEK,
DAYOFWEEK(SALES_DATE) AS DAY_OF_WEEK,
SALES_PERSON,
SUM(SALES) AS NUMBER_OF_UNITS_SOLD
FROM PRODAPPL.SALES
WHERE WEEK(SALES_DATE) = 10
GROUP BY GROUPING SETS( (WEEK(SALES_DATE), SALES_PERSON),
(DAYOFWEEK(SALES_DATE), SALES_PERSON) )
ORDER BY WEEK, DAY_OF_WEEK, SALES_PERSON
Another clause that has been added is SKIP LOCKED DATA, which allows the SQL program to continue retrieving rows from the target table when doing a query, but skip over the rows that are locked. Previously, the query would have timed out or waited for the lock to be released This is especially useful for queuing applications where rows can be processed by multiple applications in any order.
New extended indicator variable values provide a way to specify which columns in an UPDATE statement should actually be updated. Unchanged values can be tagged with a new indicator value to remove them from the update. Previously, the programmer would have had to code this with multiple update statements, and the statements would have been individually optimized.
In addition, there are several new scalar functions in V6R1:
Datetime Functions |
|
TIMESTAMP_FORMAT |
Returns a timestamp from a character string representation of a timestamp according to the specified format of the string |
VARCHAR_FORMAT |
Returns a character string representation of a timestamp, with the string in a specified format |
MONTHS_BETWEEN |
Returns an estimate of the number of months between two dates |
ROUND_TIMESTAMP |
Returns a timestamp rounded to the specified unit |
TRUNC_TIMESTAMP |
Returns a timestamp truncated to the specified unit |
String Functions |
|
ASCII |
Returns the ASCII code value of the leftmost character of the argument as an integer |
CHR |
Returns the character that has the ASCII code value specified by the argument |
ENCRYPT_AES |
Encrypts a string using the AES encryption algorithm |
Also, a new data type named DECFLOAT has been added. A form of floating point, it keeps precision accurately like a decimal number. It is an IEEE 754R number with a decimal point. Special values even allow the program to store infinity! This data type is fully supported in SQL statements. Note, however, that only the ILE/C compiler supports DECFLOAT in this release.
Also, new data type syntax has been added to support the standard way to define UTF-16 columns.
Here's an example:
CREATE TABLE myUTF16.table (
C1 NCHAR(10),
C2 NVARCHAR(20),
C3 NCLOB(1M) );
NCHAR (n) |
GRAPHIC (1) CCSID 1200 GRAPHIC (n) CCSID 1200 |
NVARCHAR (n) |
VARGRAPHIC (n) CCSID 1200 |
NCLOB (n) |
DBCLOB (1M) CCSID 1200 DBCLOB (n) CCSID 1200 |
Another nice addition is the ability to create a column that has the IMPLICITLY HIDDEN attribute. This allows programmers to define and use the column in their applications, but it effectively "hides" the column from query applications if users or programs do not explicitly specify the column.
There is also now a way to define a timestamp column that will be automatically updated whenever a row changes by using the FOR EACH ROW ON UPDATE AS ROW CHANGE TIMESTAMP clause. This clause could be used in conjunction with the IMPLICITLY HIDDEN clause to have a hidden column that is updated with the latest change timestamp for each row.
CREATE TABLE PRODAPPL.TABLE1 (
C1 INT,
C2 VARCHAR (20),
C3 TIMESTAMP IMPLICITLY HIDDEN;
SELECT * FROM PRODAPPL.TABLE1;
The result of this query will display only columns C1 and C2. C3 will be hidden from the query user's result set. But if the query is changed to include C1, C2, and C3, then it will return all columns.
SELECT C1, C2, C3 FROM PRODAPPL.TABLE1;
A significant enhancement is the ability to use expressions when creating an index. The CREATE INDEX statement now allows the use of expression notation to define the key columns. For example, SALARY + BONUS could be created as a key column in an index, which is commonly called a derived key. This will help give the optimizer a more useful key to consider when an application's query is looking for these columns combined. This support is similar to a derived key logical file. Note that an RPG program can use an index with selection using native I/O, but the program cannot use it in an SQL statement.
CREATE INDEX PRODAPPL.TOTAL_SALARY ON PRODAPPL.EMPLOYEE (SALARY + BONUS ASC)
A new capability that will be a real time-saver is the ability to use the ALTER statement to alter a function definition. Previously, the function would have to have been dropped and re-created with the new definition, and in the process any authorizations that were defined on the function were lost.
Sometimes, 50 characters were not enough text to describe constraint relationships for a programmer, so the COMMENT ON statement has been extended to constraints. The LABEL ON statement has also been extended to more SQL objects.
For programmers interested in having only one set of SQL syntax for their SQL statements while at the same time supporting multiple database targets or programmers wanting to port their SQL statement from another database to DB2 for i5/OS, many DDL statements and clauses that are unnecessary on DB2 for i5/OS will now be ignored.
Also, trigger support has been enhanced to allow the use of an INSTEAD OF trigger to be run now for each statement.
Statistics Views
Each release brings more of the database statistics out into a more accessible place, which is the database catalogs. Programmers can query these catalogs by the application to gain a rich variety of information, including statistics about table, index, and table partition usage in their database. In V6R1, several new views were added to the catalogs. Note that the first five views in the table have also been PTFed back to V5R4.
Statistics Views |
|
SYSCOLUMNSTAT |
Contains one row for every column in a table partition or table member and one row for every column statistics collection |
SYSPARTITIONINDEXSTAT |
Contains one row for every index built over a table partition or table member |
SYSPARTITIONSTAT |
Contains one row for every table partition or table member |
SYSTABLEINDEXSTAT |
Contains one row for every index that has at least one partition or member built over a table. If the index has more than one partition or member, the statistics include all those partitions and members. |
SYSTABLESTAT |
Contains one row for every table that has at least one partition or member. If the table has more than one partition or member, the statistics include all partitions and members. |
SYSINDEXSTAT |
Contains one row for every SQL index. Use this view when you want to see information for a specific SQL index or set of SQL indexes. The information is similar to that returned via Show Indexes in System i Navigator. |
SYSMQTSTAT |
Contains one row for every materialized table. Use this view when you want to see information about a specified materialized query table or set of materialized query tables. The information is similar to that returned via Show Materialized Query Tables in System i Navigator. |
SYSPACKAGESTAT |
Contains one row for each SQL package in the SQL schema |
SYSPARTITIONINDEXES |
Contains one row for every index built over a table partition or table member. Use this view when you want to see index information for indexes built on a specified table or set of tables. The information is similar to that returned via Show Indexes in System i Navigator. |
SYSPARTITIONMQTS |
Contains one row for every materialized table built over a table partition or table member. Use this view when you want to see materialized query table information for materialized tables built on a specified table or set of tables. The information is similar to that returned via Show Materialized Query Tables in System i Navigator. |
SYSPROGRAMSTAT |
Contains one row for each program, service program, and module that contains SQL statements |
Application Development
Client special registers will be very useful. Application programmers can set their own text in these registers when their applications connect and use the database. By specifying this information, programmers can have each of their client applications tagged with their own "signature." The client register information can be captured by looking at the job or by collecting an SQL Performance Monitor. This should be helpful when analyzing performance, troubleshooting, or just gathering statistics about the different client applications.
These special registers can be changed using the following:
- The Set Client Information (SQLESETI) API
- In CLI, the SQLSetConnectAttr() API
- In JDBC, the setClientInfo connection method
Client Special Registers |
|
CURRENT CLIENT_ACCTNG |
Contains the value of the accounting string from the client information specified for this connection |
CURRENT CLIENT_APPLNAME |
Contains the value of the application name from the client information specified for this connection |
CURRENT CLIENT_PROGRAMID |
Contains the value of the client program ID from the client information specified for this connection |
CURRENT CLIENT_USERID |
Contains the value of the client user ID from the client information specified for this connection |
CURRENT CLIENT_WRKSTNNAME |
Contains the value of the workstation name from the client information specified for this connection |
There have been several CLI enhancements made for application development. These include support for wide APIs, alias support in Metadata APIs, row-wise array INSERT, and complete ISO timestamp support.
JDBC has been upgraded to Version 4.0, and .Net support has been enhanced with distributed transaction support and multi-row INSERT. In addition, .Net has better integration with Visual Studio.
One of the more widely used enhancements will be the added support in embedded SQL for RPG precompiler variable scoping for local variables at a procedure level. Also, all the ILE SQL precompilers have added stream file support so that a stream file can now contain SQL statements. In addition, Unicode support was added into the COBOL SQL precompiler.
For those that use the RUNSQLSTM command, support has been added to allow running SQL statements that are stored in a stream file. In addition, SQL statements in a source member are no longer limited to the first 80 characters of each line; a right margin parameter has been added to the command to specify where the end of the line should be. It has also been enhanced to allow CL commands to be run within RUNSQLSTM. These enhancements, coupled with the ability of System i Navigator's Run SQL Scripts to use source physical file members and IFS files will help simplify storing/sharing and the running of SQL statements in programming environments.
SQL Query Engine (SQE) and Runtime Performance Improvements
SQE enhancements include the use of National Language Sort Sequence (NLSS) during optimization, as well as the ability to handle more CASE statements, UDTFs, and lateral correlation, to name a few. There are many other new capabilities and performance enhancements as well.
Prior to V6R1, a QAQQINI parameter called Ignore_Derived_Index was introduced with a default of *NO. This was because queries that referenced DDS files would be sent down the CQE path and programmers would not want derived keys ignored. With V6R1, the default value of the Ignore_Derived_Index QAQQINI parameter is now *YES because programmers can now use the new CREATE INDEX syntax to define derived keys instead of DDS.
SQL runtime improvements have also been made to the database in V6R1. These include host server variable-length compression, SQL Call caching improvements, and MQT REFRESH improvements. Also, an improvement has been made to the RGZPFM command to eliminate the need for an exclusive lock when returning storage. ALTER TABLE now preserves indexes in tables with LOB columns, and performance has been improved by not requiring the rebuild of EVIs.
Database Limits Have Been Increased
SQL application and runtime limits have been increased. These include 128-byte cursor and statement names, full 64K result-set row-length support, ability to allow more than 120 columns in a GROUP BY clause, and larger in-use table size. Database object limits have also increased for the number of schemas and the number of dependent logical files. Also, ALTER TABLE can support more dependents, and the number of saved dependents has been increased.
Database Tooling, On Demand Performance Center
Leading the way for V6R1 System i Navigator database tooling enhancements is the On Demand Performance Center. This collection of function was introduced in V5R4 to greatly simplify SQL performance analysis in DB2 for i5/OS. In V6R1, two of the most interesting additions are to the SQL Performance Monitor and SQL Plan Cache Snapshot reports. Now, when users analyze a monitor or snapshot report, they can customize which columns to include in the report. Another key enhancement is that there is now a way to save the analysis reports to a comma-separated value (CSV), tab-delimited, or even spreadsheet-formatted file directly, including the report headings. Figure 1 below shows an example of this. Another enhancement is the ability to compare more than two monitors or snapshots at a high level to see if they are interesting before going to deeper analysis.
The SQL Plan Cache Show Statements dialog's usability has been greatly improved. New functionality includes additional columns and customization of the columns in the Show Statements dialog, the ability to generate a report showing all users that have run a specific statement since the last IPL, and the ability to generate a report showing all active jobs that are running the statement. In addition, a new category of snapshots called SQL Plan Cache Event Monitors has been introduced and added to the main folder list as shown in Figure 2 below. This new category will allow a programmer to set up a monitor that is actively running and will capture plans that are being pruned out of the SQL Plan Cache. When setting up these new Event Monitors, programmers will find the same filter capability as when creating an SQL Plan Cache Snapshot.
Programmers who have used Current SQL for a job in previous releases will find that the usability of this dialog has been improved and that the dialog itself has been given a new name. It is now called SQL Details for Jobs. A set of filters has been added to improve narrowing down on the jobs that are of interest. Other new capabilities include the ability to see the client register information and the ability to view the QAQQINI file in use by the job.
One of the most helpful performance tools is Visual Explain. In V6R1, an exciting new option has been added called Explain While Running. Now, when Visual Explain is chosen for an active job that has a long-running SQL statement, the Visual Explain dialog will display the actual counts in the attribute section for the appropriate nodes in the Visual Explain dialog, as shown in Figure 3. In addition, the Refresh button can be pressed to view changes in these counts as the query continues to run. Also, the capability has been added to print the attributes for a selected node. New in this release is the ability to capture SQL performance information on the Query/400 and OPNQRYF statements. Once that information is available in an SQL Performance Monitor or SQL Plan Cache Snapshot, those statements can be analyzed using Visual Explain.
The Index Advisor that was added in V5R4 has been very popular. One enhancement that was PTFed back to V5R4 was to be able to condense the index advised information. This option shows the same index advised information but has additionally condensed the advised indexes into the most useful ones. Another useful item is the ability to right-click on one or more Index Advised rows and generate the CREATE INDEX SQL statements in a Run SQL Scripts window as shown in Figure 4. Once they are in the Run SQL Script window, they can be saved for later use in a change management system.
Many times, Show Indexes is used in conjunction with the Index Advisor to see if the optimizer is actually using the indexes that were created from the advice. The Show Indexes function has been enhanced so that Show Indexes can now be done at the schema level by right-clicking on the Tables folder of the schema. Show MQTs has also been given this capability for both tables and views. Also, the optimization usage counts that are shown can now be reset on individual indexes or tables. Finally, at times there are indexes that might share an access path with a primary key. Now, the indexes shown in the Indexes folder will contain the owning access path information, which would point to perhaps a primary key as the owner of that access path. This is shown in Figure 5.
Health Center
A very useful addition to the Health Center is a new tab called Environmental Limits. This tab lists the jobs on the system that are consuming specific database resources. These resources have known resource limits, but the key benefit is that application programmers may not have understood them or have had an easy way to view them until now. Figure 6 shows which job is consuming the resource and identifies whether the job is active or not. The blue gear icon means that it is active. If the job is active, additional drill-down options are available, including the ability to get more detailed job information and start a SQL Performance Monitor.
Another tab called Activity has been added also, as shown in Figure 7. These categories are interesting counts that someone might want to keep track of as the database is being used and growing. The Overview tab has also added counts for journals and journal receivers, and the Size Limits tab has added counts for SQL package and program sizes.
Run SQL Scripts
By far, the most-used database capability in System i Navigator seems to be the Run SQL Scripts tool. The most interesting addition to this tool is the ability to save the result set window rows to a CSV, tab-delimited, or spreadsheet-formatted file, which includes the capability to choose whether to include the column headings or not.
Speaking of headings, there is now a setting that you can use to change whether the result set window will display column headings instead of the column names. See Figure 8.
Another addition is the ability to print the contents of the result-set window. Also, there is now the ability to save the script to a UTF-8 or a source physical file member in i5/OS. There are numerous other usability enhancements as well. For instance, font support has been extended to the result-set window. And a new option was added to the Run SQL Scripts application to allow for checking SQL statements for portability.
General Enhancements and the Web
Many other System i Navigator database enhancements have been made. For example, there is now a Show Object Locks option for tables, views, and indexes. And programmers now have the ability to add a comment to any of the database objects to write more-descriptive text. Column and sort capabilities were added to many of the folder lists, and the Generate SQL menu option can now be used from any of the database object folder menus. In addition to the System i Navigator interface, many of the same dialogs discussed can be used in the Web application called IBM Systems Director Navigator for i5/OS.
Wrapping It Up
This article has highlighted many V6R1 functions and enhancements by organizing them in the categories of SQL syntax, new catalog statistic views, application development, SQL Query Engine (SQE) and performance, increased limits, and the System i Navigator database tools.
For application designers and programmers, this lineup shows that DB2 for i5/OS continues to provide a rich and powerful set of functions and enhancements in each release. These new capabilities will help application designers and programmers continue to produce new and exciting applications for i5/OS.
LATEST COMMENTS
MC Press Online