21
Sat, Dec
3 New Articles

Practical SQL: OLAP, Part 1

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

Online Analytical Processing (OLAP) adds a variety of processing features to SQL syntax that makes it much more useful as an ad hoc analysis tool, and this article introduces the first of those functions.

 

SQL has always been a great tool for querying data. The problem is that SQL doesn't always lend itself to the sort of pattern analysis that's needed in enterprise data processing. Something goes awry in the database and the only way to identify the source of the problem is to backtrack through history. Let me give you a real-world example (the data has been changed to protect the innocent, but the situation is pretty common).

Where Did All This Inventory Come From?

The situation is a traditional ERP shop that handles lots and lots of inventory transactions: receipts, issues, transfers, adjustments, you name it. Multiple systems are involved—from purchasing and receiving through manufacturing to warehouse management and shipping. Transactions come from shop floor control, shipping and receiving, and everything in between, including manual adjustments and even EDI.

 

Modifications are made to the systems over the years to make life a little easier for everyone, and, generally speaking, the system is a great success.

 

But suddenly one day a problem is noticed when the system's trying to execute an issue. A whole lot of inventory is missing! After an initial mad scramble to identify the problem, it's found that it's not that inventory is missing, it's just that some inventory locations have been over-reported: the database shows more inventory than actually existed. And now the hunt is on to identify the cause.

 

The good news is that there's an inventory transaction file that keeps historical information. (Even if you don't have a transaction file, as long as your files are journaled, you can extract the changes and then query them, a technique we'llcover another day.) A quick review of the file shows the following:

 

 

ITITEM

ITEVENT

ITFROM

ITLOC

ITQTY

ITTXID

ITEMA

ADJUST

 

BIN-C-7

-15000

102019887343

ITEMA

ADJUST

 

SCRAP

15000

102019887346

ITEMA

RECEIPT

 

DOCK1

10000

102029302132

ITEMA

TRANSFER

DOCK1

BIN-A-1

10000

102029433231

ITEMA

ADJUST

 

BIN-A-1

10000

102029434501

 

 

The transaction file has five primary fields: the item number, the event, the from location, the to location, and the quantity. There's also a unique transaction ID that is incremented by one for every record written to the file. Compare the first two records; these records together form an inventory movement: 15000 units of inventory is adjusted out of location BIN-C-7 and subsequently 15000 units is adjusted into location SCRAP. When the system was originally written, all inventory movement worked this way: data was adjusted out of one location and into another. In fact, at that time the file only had one location, ITLOC. The ITFROM field was added recently as part of a change that allowed a single TRANSFER event to take the place of two adjustments. The QC application (used to scrap inventory) still uses the older two-adjustment method, but the warehouse put-away application has been updated to use the new single-record technique.

 

Except that there seems to be a problem. Originally, when a truck was unloaded, the system did all the receipts, then did all the adjustments off the DOCK location, and then finally did all the adjustments to the put-away locations. These were three separate processes. The put-away process was modified to use TRANSFER transactions, but evidently under certain circumstances the second adjustment is still being processed. So now we see a TRANSFER that removes inventory from the DOCK1 location and increases the BIN-A-1 location, followed by a second ADJUST transaction, which also increases BIN-A-1. And now we've got double inventory and bad things are going to happen.

Using OLAP

It's pretty easy to see the problem by reviewing the data for this item. However, the next part is tougher: how do we use SQL to find all the cases where this has occurred? It would be relatively easy with an RPG program: read through the file by item and transaction ID, set a flag when a TRANSFER is read, and check the next record to see if it's a duplicate adjustment (the same location and quantity). But that concept of "nextness" isn't always easy to come by in SQL. In fact, in this situation it's nearly impossible, because the only thing we can say is that the transaction ID of the adjustment has to be greater than the transfer but with no other records in between. You can do that in SQL, but it's a little bit of a stretch; you probably have to use a JOIN as well as a WHERE NOT EXISTS. I'll leave that exercise to the user.

 

With OLAP, it's actually relatively simple. Here's the query:

 

with T1 as (select INVTRN.*,                              

row_number() over (order by ITITEM, ITTXID) as E_NUMBER  

from INVTRN)                                              

select A.ITITEM, A.ITEVENT, A.ITTO, A.ITQTY, A.ITTXID,            

                 B.ITEVENT, B.ITTO, B.ITQTY, B.ITTXID

from T1 A join T1 B using (ITITEM)                      

where A.E_NUMBER = B.E_NUMBER - 1                      

       and A.ITEVENT = 'TRANSFER' and B.ITEVENT = 'ADJUST'

        and (A.ITLOC, A.ITQTY) = (B.ITLOC, B.ITQTY)        

 

At first glance it may be a little cryptic, but let me break it down. There are really just two simple parts. The first part is a common table expression (CTE) that attaches an OLAP function to the file. The first three lines basically create a CTE named T1, which consists of all the fields from INVTRN as well as the row_number OLAP function. The row_number function simply generates a unique, sequential row number for each record in the query. The syntax of row_number (and this is common among all OLAP functions) allows you to specify the order that the records are looked at when the function is being processed. So, as specified, the field E_NUMBER contains a sequential number starting at 1 for the first record in ITITEM/ITTXID sequence and working its way up. There are many other functions, and variations of the syntax allow you to execute these functions over subsets of the data. I'll go into those issues in more detail in subsequent articles.

 

After that, the query is pretty straightforward. I join the CTE against itself by item number. This allows me to directly compare all the records for one item to each other. The next line is the money line: I compare only those pairs where the first entry's row number is equal to the second entry's row number minus one. That is, the first entry directly precedes the second entry. This is the part that would have taken a pretty significant SQL statement (as I said, probably requiring a WHERE NOT EXISTS) but instead is now a very simple comparison, which you can use as a template for any similar requests. The next two lines then apply the business logic: a TRANSFER followed by an ADJUST with the same location and amount.

 

If you run the query against just the records above, you get this:

 

ITEMA     TRANSFER BIN-A-1   10,000.00   102029303231     ADJUST   BIN-A-1   10,000.00   102029434501

 

And that's exactly what we expect. More importantly, it would work no matter how many records were there, as long as there were no records for that item between the two, and it would also show any other record pairs where this occurred.

 

I'll follow this article up with some more examples introducing more of the OLAP functions and their variations.

 

P.S. If you run this on a machine at V5R4, the first field in the select must be qualified; that is, it must be A.ITITEM. However, in subsequent releases the ANSI standard of not qualifying fields in a USING clause applies, so you would instead only select ITITEM (all the other fields must remain qualified). Just a word to the wise. Have fun!

 

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: