TechTip: V5R3's New SQL BIFs, Part 1

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

One of the most powerful features of Structured Query Language (SQL) is the use of built-in functions (BIFs). In V5R3, IBM enhanced the set of BIFs supported by the DB2 UDB for the iSeries implementation of SQL. In fact, 25 new BIFs have been added. In this TechTip, we'll explore the five new data partitioning BIFs.

Data Partitioning

Data partitioning allows you to spread the data in a single table across multiple iSeries systems and/or logical partitions (LPARs) to increase scalability and reliability. Query performance can also be increased because pieces of the query can run at the same time on different servers. The data partitioning features of DB2 UDB for iSeries are achieved through the add-on component DB2 Multi-System. To support data partitioning in V5R3, IBM added five new BIFs.

To understand these functions, you need to understand how partitioning works. Within data partitioning, data is spread across multiple servers or partitions. The group of partitions is referred to as a "node group." A node group consists of anywhere from 2 to 32 nodes. Partitioning is the means by which data is spread across nodes. A partitioning key, which is defined using fields within the table being partitioned, is used to associate the data being partitioned with the node containing the data.

Now that we've covered the concept of partitioning, let's look at the new SQL functions you can use to access partition information.

SQL Partition Functions

To facilitate the retrieval of information related to data partitioning, DB2 supports the new functions shown in the table below.

Data Partitioning Functions
Function
Description
DATAPARTITIONNAME
Returns the partition name for the current row of the table designator provided
DATAPARTITIONNUM
Returns the partition number of the partition containing the current row for the table designator provided
DBPARTITIONNAME
Returns the relational database name for the current row of the table designator provided
DBPARTITIONNUM
Returns the relational database node number of the partition containing the current row for the table designator provided
HASHED_VALUE
Returns the partition map index number of the partition containing the current row for the table designator provided


The example below illustrates the use of the DATAPARTITIONNAME function.

SELECT DATAPARTITIONNAME(A) 
FROM MYLIB.SOMEFILE A

In this example, the data partition name for each row in the file SOMEFILE in the library MYLIB is displayed. Note that the table designator "A" is specified after the file name to allow us to associate this table designator with the file on the DATAPARTITIONNAME function. This example uses the SQL naming convention. If your application uses the SYS (or SAA) naming convention, the file and library name will be represented as MYLIB/SOMEFILE. When executed, this function returns a list similar to that shown in Figure 1.

http://www.mcpressonline.com/articles/images/2002/FaustSQL_tech_tip_1V4--04150500.png
Figure 1: The DATAPARTITIONNAME function generates this output.  (Click images to enlarge.)

This example indicates that the table exists in a node group containing four nodes: SERVERA, SERVERB,SERVERC, and SERVERD. If this function is used with a table that is not partitioned, a blank value is returned.

The example below illustrates the DATAPARTITIONNUM function's use.

SELECT DATAPARTITIONNUM(A) 
FROM MYLIB.SOMEFILE A

As with the prior example, one row is returned for each record in the specified table. When executed, this function returns a list similar to that shown in Figure 2.

http://www.mcpressonline.com/articles/images/2002/FaustSQL_tech_tip_1V4--04150501.png
Figure 2: The DATAPARTITIONNUM function generates this output.

As with the DATAPARTITIONNAME function, this example indicates that the function was called on a partitioned table stored in a node group containing four nodes. If this function is executed on a table that is not partitioned, a value of 0 is returned for all records.

The DBPARTITIONNAME function performs a similar function to the DATAPARTITIONNAME function but when used on a non-partitioned table, it returns the value of the CURRENT_SERVER special register. Similarly, the DBPARTITIONNUM function is, for all intents and purposes, the same as the DATAPARTITIONNUM function. As with DATAPARTITIONNUM, DBPARTITIONNUM returns a 0 value for all rows when used on a non-partitioned table.

The HASHED_VALUE function returns the partition map index number of the partition that contains the current row for the table specified. Hashing is the means by which the values of a table's key field or fields are associated with a specific partition number. The value returned by this function is similar to what is returned by the DBPARTITIONNUM or DATAPARTITIONNUM functions, but hashing is used to retrieve the partition number based on the supplied table's key field. The SQL statement below illustrates this function's use.

SELECT HASHED_VALUE(A), FIELD1
FROM MYLIB.SOMEFILE A
     WHERE HASHED_VALUE(A) = 4

When executed, this statement returns all rows where the partition number is 4. As with the other functions listed, a 0 is returned if this function is executed on a table that is not partitioned.

Scratching the Surface

Since our focus here has been SQL functions, I have not covered data partitioning in as much detail as you might like. For additional information on this powerful concept, check out "iSeries DB2 Multisystem V5R3." For more information on SQL functions, look for SQL Built-In Functions and Stored Procedures: The i5/iSeries Programmer's Guide.

Mike Faust is an application programmer for Fidelity Integrated Financial Solutions in Maitland, Florida. Mike is also the author of the books The iSeries and AS/400 Programmer's Guide to Cool Things, Active Server Pages Primer, and SQL Built-In Functions and Stored Procedures. You can contact Mike at This email address is being protected from spambots. You need JavaScript enabled to view it..

Mike Faust

Mike Faust is a senior consultant/analyst for Retail Technologies Corporation in Orlando, Florida. Mike is also the author of the books Active Server Pages Primer, The iSeries and AS/400 Programmer's Guide to Cool Things, JavaScript for the Business Developer, and SQL Built-in Functions and Stored Procedures. You can contact Mike at This email address is being protected from spambots. You need JavaScript enabled to view it..


MC Press books written by Mike Faust available now on the MC Press Bookstore.

Active Server Pages Primer Active Server Pages Primer
Learn how to make the most of ASP while creating a fully functional ASP "shopping cart" application.
List Price $79.00

Now On Sale

JavaScript for the Business Developer JavaScript for the Business Developer
Learn how JavaScript can help you create dynamic business applications with Web browser interfaces.
List Price $44.95

Now On Sale

SQL Built-in Functions and Stored Procedures SQL Built-in Functions and Stored Procedures
Unleash the full power of SQL with these highly useful tools.
List Price $49.95

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: