25
Wed, Dec
0 New Articles

Practical SQL: Complex Summarization

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

Common Table Expressions (CTEs) make complex data summarization easy.

Common Table Expressions, or CTEs, are one of my favorite tools in SQL. Simply put, they allow you to encapsulate your business logic. I’ve written in the past about how to use CTEs to encapsulate data arithmetic. However, you can generalize that encapsulation further, and lately I’ve been doing a lot of that.

Data Analysis

One of my primary roles in our organization is data analysis. Whether it’s reviewing business process changes over time or identifying edge conditions in transactions, SQL is my primary tool for any number of activities. Whether you use the green-screen STRSQL utility or a PC client such a DBeaver (which I talk about in this article), SQL is a great way to dig into data and present it to the business.

What I find myself doing a lot is organizing data. This organization is based on data points in the ERP, and the categorization can get pretty involved. For example, I might need to group inventory by warehouse, where certain warehouses belong to a group. The groups may be somewhat ad hoc, so I have to figure out how to aggregate by that ad hoc grouping. Another case might be grouping by general ledger event types, maybe selecting costing separately from inventory movements. Yet another case may be when a field has a number of values, but you need to segregate by ranges. For example, you might want to accumulate two different totals based on whether an invoice has a zero or non-zero amount.

You may be saying to yourself that this is the job of a CASE statement. And indeed you would be correct. However, the problem with CASE statements comes when you try to group by them. It’s not impossible, certainly, but it does require a syntactical technique that makes it ungainly.

A Real Example

Rather than try to provide examples of made-up business data, I think I can present all of the issues using a built-in table from the IBM i itself. I actually use this when wearing one of my other hats, my system architecture hat. Let’s start with a very simple case.

SELECT * FROM TABLE(object_statistics('MTLIB', '*PGM'))

This is a very useful SQL query, and one that is the basis for a lot of my architecture analysis. The object_statistics table function is the SQL interface to the DSPOBJD API. It allows you to get a list of objects in a library (or in a group of libraries using special values like *LIBL). The statement as shown gives you a list of all the program (object type *PGM) in the library MYLIB. What can I do with that? Well, one thing I can do is see whether the programs have been used or not since they were created. The last_used_timestamp field contains, as its name suggests, the timestamp of the last time the object was used. But if I want to count the used and unused programs, I can’t just group by last_used_timestamp, because the timestamp is probably different for every program that was used. Instead, I’d want to group by a yes/no flag. Getting that flag is relatively easy:

SELECT CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END WasUsed

FROM TABLE(object_statistics('MTLIB', '*PGM'))

That’s pretty straightforward. If the timestamp is null, the WasUsed field is N; otherwise, it’s Y. However, if I want to get a count of each, I run up against one of the idiosyncrasies of SQL: if I want to group by a derived field, I must repeat the computation in the GROUP BY clause. So the statement ends up like this:

SELECT CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END WasUsed,

count(*) Cnt

FROM TABLE(object_statistics('CUSTOM8', '*PGM'))

GROUP BY CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END

WasUsed     Count

N           1307

Y           1450

As you can see, it gives me a nice result, but, as I noted, the syntax is very ungainly. And the more conditions I add, the worse it gets. Let’s say I just want to add one more condition, the program model. The easiest way to determine the program model for a program is to see whether the object attribute has LE in it: that is, such as RPGLE or CLLE. But just take a look at what happens to the Select statement as we add that second CASE:

SELECT CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END WasUsed,

CASE WHEN objattribute LIKE '%LE%' THEN 'ILE' ELSE 'OPM' END Model,

count(*) Cnt

FROM TABLE(object_statistics('CUSTOM8', '*PGM'))

GROUP BY CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END,

   CASE WHEN objattribute LIKE '%LE%' THEN 'ILE' ELSE 'OPM' END

ORDER BY 1 DESC, 2

So now I have two rather verbose derived values, both of which I have to duplicate, leaving me open to maintenance issues. The good news is that if I do make an editing mistake, the SQL validator will catch it, but it’s still a lot of work. And that’s finally where the CTE comes in.

WITH T1 AS (SELECT

CASE WHEN last_used_timestamp IS NULL THEN 'N' ELSE 'Y' END WasUsed,

CASE WHEN objattribute LIKE '%LE%' THEN 'ILE' ELSE 'OPM' END Model

FROM TABLE(object_statistics('CUSTOM8', '*PGM')))

SELECT WasUsed, Model, count(*) Cnt FROM T1

GROUP BY WasUsed, Model ORDER BY 1 DESC, 2

WasUsed     Model Cnt

Y           ILE   511

Y           OPM   939

N           ILE   426

N           OPM   881

I create my CTE with the name T1, and in it I define all of my derived values. And the nice thing is that you can test the SELECT all by itself, just to make sure you’re getting the data you want. Once the CTE is debugged, then I put it in the WITH … AS clause, creating the CTE, and then subsequently I select those derived fields by name to group and order the results. Note that I can actually define the ORDER BY clause using the column positions. That works really well, but I have to be careful when I move the columns around in my SELECT statement. Obviously, there are pros and cons to this approach, and you can pick the one that best suits your needs.

Another Option

CTEs aren’t the only option for aggregating data using a derivation, particularly when you’re grouping together sets like the program model. You can also create a temporary table with each of the values, such as RPG or RPGLE, pair it with the model, and then JOIN to it. But since the CTE handles that condition as well as many others, it’s the one I lean on the most.

Hopefully, this will give you another way to look at your data.

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: