19
Fri, Apr
5 New Articles

An SQL Function That Brings Back Memories of the Past

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

Not everything that's old is outdated!

 

In my previous article, I discussed the goals I had set out for our programming group and how those goals helped determine the skills that I was looking for among the candidates for a job in our company. One of those goals was to encourage the use of SQL among our programmers for database I/O.

 

There are lots of reasons for this, including the facts that SQL is a standard database access language that can be used across many systems and programming languages and that the SQL query engine is the only one that IBM is enhancing on the IBM i to improve efficiency in data access. Of course, many other reasons have been listed by other authors here before. My main argument to my programmers, however, is that it makes your programming so much more efficient, especially if you take advantage of some of the more than 100 SQL functions that are available in the language on the IBM i. Furthermore, if you don't find the function you need, you can create your own user-defined function. So if you're stuck on the basics and just using SELECTs to retrieve and sort data in your programs, then you're missing out on the true power of SQL. The IBM Infocenter has a handy list of these functions.

 

If you're new to SQL or want to move beyond the basics, one book I'd recommend is SQL for eServer i5 and iSeries by Kevin Forsythe. It is well-written, gives a nice overview of the language, and has enough examples that you'll want to keep it as a reference.

 

To illustrate why SQL helps you to be more efficient as a programmer, I'd like to look at a situation that happened in our shop and discuss one unusual SQL function I had not used before that we used to solve the problem quickly. I'll conclude with some caveats on its use with SQL.

 

As part of our daily routine, our system copies invoices that have been paid from a current invoice file to an invoice history file. Due to an unusual set of circumstances that I won't discuss here, the invoice records for one day were copied twice, creating duplicate invoice records in our history file. While there are a number of ways to remove the duplicate records, one very easy way is with the use of an SQL statement that includes two functions: the Relative Record Number function RRN and the Minimum function MIN.

 

For this example, I've abbreviated our INVOICE table so that each row consists of a customer number, an invoice number, the date sold, and the total dollars.

 

CUSTNO

INVCNO

DATSLD

TOTAL

10658

5717045

20120614

118.64

12546

5717041

20120614

222.76

7056

5717132

20120614

398.36

 

After the invoice records were inadvertently copied twice, the INVOICE table looked as shown below:

 

CUSTNO

INVCNO

DATSLD

TOTAL

10658

5717045

20120614

118.64

12546

5717041

20120614

222.76

10658

5717045

20120614

118.64

7056

5717132

20120614

398.36

12546

571741

20120614

222.76

7056

5717132

20120614

398.36

 

 

Now let's look at the SQL statement that was used to delete the duplicate records.

 

DELETE from INVOICES A

where rrn(A) > (SELECT Min(rrn(B)) from INVOICES B where A.invcno = B.invcno)

 

In this case, we're using the rrn() function to help uniquely identify each row in the table. In the subquery, we're finding the row with the smallest relative record number for each unique invoice number by using another function, min(), to take the minimum of the result of the relative record number function for those rows with matching invoice numbers. In the main clause, we use the DELETE statement to delete all rows whose relative record number is greater than the minimum. In the case of our file, we had two rows for each invoice, but the above statement will remove all duplicate rows no matter how many there are, since it is deleting all rows with the same invoice number that have a relative record number greater than the minimum. Finally, we're using two alias table names for the INVOICE table, A and B, so we can join the INVOICES table to itself with invcno in the subquery SELECT.

 

Before this problem occurred, I don't think I had thought about relative record numbers since the days of the System/34/36, and I frankly didn't realize that IBM had an SQL function to retrieve them. In a more modern table with an identity column, I wouldn't have needed rrn(), since I could have used the identity instead to uniquely identify the rows. In that case, the DELETE statement above would be the same, with the substitution of the identity column name for the rrn() function, and then we'd use the min() to find the minimum identity value. However, in this case, it was a simple table that had no identity column, and the rrn() function certainly came in handy.

 

One note of caution: You might be tempted to view the rrn() as something similar to either an identity for a row or a number representing the relative position of a row in a table. For example, if rrn(A) = 3, then it's referring to the third row in the table. This is not the case. After deleting the duplicate records from INVOICES, we can review the table with the following SQL command:

 

SELECT CUSTNO, INVCNO, DATSLD, TOTAL, rrn(A) from INVOICES A

 

You might have expected to see three rows with relative record numbers 1, 2, and 3. If so, you would be surprised to see the following:

 

 

CUSTNO

INVCNO

DATSLD

TOTAL

RRN

10658

5717045

20120614

118.64

1

12546

5717041

20120614

222.76

2

7056

5717132

20120614

398.36

4

 

This is because there are deleted records in the DB2 file that retain their relative record numbers, and we had actually deleted records 3, 5, and 6. If we added another record to the file, and the file is defined not to reuse deleted records, then our next record would be relative record number 7. Furthermore, if we were to reorganize the physical file, then the relative record numbers would be sequenced back to 1 – 3.

 

Finally, it's important to remember that when accessing records through a logical file or view, the rrn() function returns the relative record number of its base table, not the view. Similarly, if using a distributed or partitioned table, then the rrn() function identifies the relative record number of the row in the partition or the distributed table where it is found; in that case, the rrn() function will not be unique.

 

In summary, this was an interesting function to use with SQL to access some DB2 information that was being kept about our INVOICES table, and it did exactly what we needed it to do in this particular case. A word of caution should be noted: When mixing older file concepts with SQL, make sure you're aware of the consequences.

 

Jim Staton

Jim Staton is Vice President for Information Technology at Mutual Distributing Company, the largest alcohol beverage distributing company in North Carolina.

 

While Jim never worked with IBM midrange systems at IBM, one of his first programming jobs was developing software for an IBM System/3 Model 6 for his family's business. He continued to develop RPG applications for the business in his spare time on a System/32, System/34, System/36, and eventually the AS/400.

 

In 1978, Jim joined IBM at the Research Triangle Park in North Carolina, where he worked with computer communications and protocol standardization. As a manager at IBM, he was responsible for IBM's work with the IEEE 802.x committees to complete the standards for the 802.2-5 protocols for local area networks. In 1985, Jim joined the IBM European Networking Center in Heidelberg, Germany, where he managed the development of IBM's first prototype implementing the CCITT X400 Standard, which were the rules governing the first universal email system. While at IBM, Jim was awarded two patents in communication protocols as well as an Outstanding Technical Achievement Award for his work with X.400 Message Handling System. He also coauthored several articles on computer communications for the IBM Systems Journal.

 

Jim has been a speaker at a number of conferences on a variety of topics, including communications protocols, supply chain management, mobile applications, and business intelligence.

 

Jim graduated from Ohio State University in 1978 with an MS degree in Computer Science.

 

 

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$0.00 Raised:
$

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: