02
Sat, Nov
2 New Articles

TechTip: Create an SQL Function to Split a Delimited List

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

With the aid of a recursive query, add a SPLIT function (common to many programming languages) to your DB2 for i toolbox.

 

Many programming languages, such as Visual Basic, C#, Java, JavaScript, and others, have a "split" function. Split allows a developer to take a single string containing a delimited list of items and separate the individual items into a dynamically sized array. Every so often, I find myself longing for a similar function in DB2 for i's SQL. While DB2 for i doesn't have a SPLIT function, it is very easy to create one by embedding the power of recursion within a table function. But instead of splitting the list into an array, the table function will split each item into a separate row within a result set. The technique shown in this tip requires DB2 for i V5R4 or higher.

 

Before delving into code, let's look at an example of why a SPLIT function is useful within SQL. Say a Web or GUI client is designed to let users inquire against the database based on various filter criteria. Further, say some of the filter selections can allow for multiple values. For example, the quarter selection list shown in Figure 1 will let the user select multiple quarters:

 

022213SansoterraFigure1                       

Figure 1: The list box will allow a user to select from zero to many quarters.

 

When the user selects multiple quarters, how should the client pass those multiple values to the database for processing? In this case, one approach is to let the user pick a maximum of 10 quarters and then create a stored procedure that defines 10 quarter parameters.

 

A better alternative is to have the client join the selected values in a delimited string (e.g., "2010-Q1,2011-Q1") and pass it as a single parameter to a stored procedure. The stored procedure will use the SPLIT function to break apart the list of values and return results accordingly. The advantage of this solution is that it isn't bound to a specific number of parameterized values.

 

Here's a little more detail on how the solution would be implemented. Assume that a SPLIT User-Defined Table Function (UDTF) is installed on your system and it accepts two parameters: the data (or delimited string) and the delimiter.

 

When passed multiple values, the SPLIT table function will convert the delimited list (in this case assuming a pipe character (|) delimiter) to a set of rows.

 

SELECT *

FROM TABLE(QGPL.SPLIT('2010-Q1|2011-Q1|2012-Q1|2013-Q1','|')) LIST;


The results of the table function include two columns: ID and VALUE. The ID is an incremental row number that can be useful in circumstances when the position or order of the element within the list is important. The VALUE column is just an item that was extracted from the list. In the case where the delimiter is placed at the beginning or end of the input, or where two delimiters are sandwiched together, the VALUE column will hold an empty string. The maximum size of an element to split (although it can be modified) is 256 characters.

 

The result of the above query is shown in Figure 2:

 

ID

VALUE

1

2010-Q1

2

2011-Q1

3

2012-Q1

4

2013-Q1

Figure 2: Here's a sample result set from the SPLIT UDTF.

 

So SPLIT converts a list into rows and columns, which is something SQL is good at manipulating. A sample query that takes advantage of the SPLIT UDTF might look like this:

 

SELECT *

FROM ORDER_HEADER

WHERE QTR_ID IN (

SELECT CAST(VALUE AS CHAR(7))

FROM TABLE(SPLIT('2010-Q1|2011-Q1|2012-Q1|2013-Q1','|')) LIST);


Of course, if this query were embedded in a stored procedure, the list of values would be a parameter or variable name instead of a literal.

 

Marching on, let's discuss the code involved with the SPLIT function. The DB2 for i code shown below is used to create a User-Defined Table Function (UDTF) called SPLIT. As for the code, I must give credit where credit is due. I filched this idea from a website that specializes in SQL Server tips.

 

In this tip, the author Mickey Stuewe discussed the very same multi-select problem when using SQL Server Reporting Services (which can be configured to allow users to select multiple values for a report, similar to the scenario described above). Stuewe published a brilliant T-SQL table function to parse a delimited string. I converted the function to DB2 for i (with a few minor changes), which is shown here:

 

CREATE FUNCTION QGPL.SPLIT (

@Data     VARCHAR(32000),

@Delimiter VARCHAR(5))

 

RETURNS TABLE (

ID   INT,

VALUE VARCHAR(256))

 

LANGUAGE SQL

DISALLOW PARALLEL

DETERMINISTIC

NOT FENCED

 

RETURN

WITH CTE_Items (ID,StartString,StopString) AS

(

   SELECT

       1 AS ID

       ,1 AS StartString

       ,LOCATE(@Delimiter, @Data) AS StopString

   FROM SYSIBM.SYSDUMMY1

   WHERE LENGTH(@Delimiter)>0

     AND LENGTH(@Data)>0


UNION ALL


   SELECT

       ID + 1

       ,StopString + LENGTH(@Delimiter)

       ,LOCATE(@Delimiter, @Data, StopString + LENGTH(@Delimiter))

   FROM

       CTE_Items

   WHERE

       StopString > 0

)

SELECT ID, SUBSTRING(@Data,StartString,

       CASE WHEN StopString=0

           THEN LENGTH(@Data)

           ELSE StopString-StartString END)

FROM CTE_Items;

There's not much to this function. A recursive common table expression (RCTE) is used to find the starting and ending character positions of all the items in the data string. The delimiter, of course, identifies the end of a data item and the start of the next. The "prime" query in the RCTE identifies the first and last positions of the first data item. The "recursive" portion of the query in the RCTE identifies all the starting and ending positions of the remaining items contained in the list. If you're not familiar with RCTEs, please review the references at the end of this tip.

 

A few additional notes to consider:

  • When on i7.1, the code can be changed to use the "CREATE OR REPLACE" syntax. Also, the DISALLOW PARALLEL option is not required.
  • For table functions, the default cardinality is assumed to be 1000 rows. This means, when creating an execution plan for the query, DB2 will assume the table function will return 1000 rows on average, and that will be a major consideration for where the table function is placed in the join order. If, on average, you expect the cardinality to be much smaller than 1000 rows, you can specify the estimated number of rows using the CARDINALITY keyword on the CREATE FUNCTION statement. (e.g., CARDINALITY 50).
  • Perhaps you're wondering whether the recursive query against a long string will hit a nesting limit and cause a query to fail. The answer is yes, but for reasonable strings it shouldn't be a problem. On a V5R4 system, the function successfully parsed a string of over 1000 delimited values without a hiccup.
  • IBM i 7.1 supports an ARRAY data type that can be converted to a result set using the UNNEST table function. Also, XML can be used to pass multiple values in a single parameter that can be parsed with the XMLTABLE table function. When possible, I usually encourage the use of arrays or XML to pass related data in a single parameter (as opposed to an unstructured string). However, a limitation of using arrays is that they're currently supported only from a Java client or another SQL routine. Parsing XML can also be a resource-intensive operation, so passing delimited strings is still in some cases an acceptable option.

 

Having a SPLIT function in your database can be useful in a vast number of situations. For instance, filter criteria selections are often combined into a single parameter to avoid the pain of defining multiple parameters of an unknown quantity. Or, in a client/server scenario, multiple data elements may be consolidated so that only a single call is made to the database server from the client (instead of passing small amounts of data using successive database calls), etc. When these types of solutions are architected, SPLIT is a key to allowing the database to handle them.

References

Practical SQL: Don't Be Afraid of Recursion

TechTip: DB2's CONNECT BY Simplifies Recursive Processing

Recursive query optimization (IBM DB2 i 7.1 documentation)

Michael Sansoterra is a DBA for Broadway Systems in Grand Rapids, Michigan. He can be contacted at This email address is being protected from spambots. You need JavaScript enabled to view it..


BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • 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.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • 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

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • 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: