24
Wed, Apr
0 New Articles

TechTip: Access Packed Data in "Flat Files" with a Table Function

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

Awhile back, I wrote a TechTip on accessing packed data from flat files. Perhaps that's not something you do every day, but it's definitely something that is difficult for SQL to do. That TechTip outlined the basic method for extracting the packed data. But it stopped at that point. Birgitta was kind enough to post on the MC Press forums a suggestion that a table function would simplify the process. That's a great idea! In this article, I'll explain how to use both a scalar function and a table function to extract the data and simplify the whole process!

The final version of the code from the previous TechTip is as follows, with the results displayed in Figure 1:

SELECT SUBSTR(CUSTFLAT,4,30),
DECIMAL(SUBSTR(HEX(SUBSTR(CUSTFLAT,1,3)),1,5),5,0) * CASE
WHEN SUBSTR(HEX(SUBSTR(CUSTFLAT,3,1)),2,1) ='F' THEN 1 
ELSE -1 END
FROM CUSTFLAT


http://www.mcpressonline.com/articles/images/2002/TechTip%20Table%20functionV3--03250500.png

Figure 1: Manually extract data from customer master flat file. (Click image to enlarge.)

The code extracts the customer name from columns 4 through 33 and the customer number from columns 1 through 3. The code for unpacking the data is fairly complex and is a pain to write even once, let alone every time you have data to unpack. An improved solution is to use a scalar function to unpack the data. We can create a new scalar function, named UNPACK, with this code:

CREATE FUNCTION UNPACK(Rcd VarChar(1000), Start Integer,      
Len Integer, Dec Integer)                                     
RETURNS VARCHAR(30)                                           
LANGUAGE SQL                                                  
DETERMINISTIC                                                 
BEGIN                                                         
Declare Data Char(30);                                        
Declare ULen Integer;                                         
Declare Sign Integer;                                         
Set Ulen = Len *2-1;                                          
Set Data = SUBSTR(HEX(SUBSTR(Rcd,Start,Len)),1,Ulen);         
Set Sign = CASE                                               
WHEN SUBSTR(HEX(SUBSTR(Rcd,Len,1)),2,1) ='F' THEN 1           
ELSE -1                                                       
END;                                                          
IF Dec = 0 Then                                               
   Set Data = Char(Decimal(Data,30,0)*Sign); 
ELSEIF Dec = 1 Then                                             
   Set Data = Char(Decimal(Decimal(Data)/10,30,1)*Sign);        
ELSEIF Dec = 2 Then                                             
   Set Data = Char(Decimal(Decimal(Data)/100,30,2)*Sign);       
ELSEIF Dec = 3 Then                                             
   Set Data = Char(Decimal(Decimal(Data)/1000,30,3)*Sign);      
ELSEIF Dec = 4 Then                                             
   Set Data = Char(Decimal(Decimal(Data)/10000,30,4)*Sign);     
ELSEIF Dec = 5 Then                                             
   Set Data = Char(Decimal(Decimal(Data)/100000,30,5)*Sign);    
ELSE Set Data = Char(Decimal(Decimal(Data)/1000000,30,6)*Sign); 
END IF;                                                         
RETURN Data;                                        
END                                         


This new user-defined function named UNPACK can extract a packed value from a string. It supports 0 to 6 decimal places, and more can be handled by simply expanding the ELSEIF logic. The function is used as follows:

SELECT SUBSTR(CUSTFLAT,4,30), UNPACK(CUSTFLAT,1,3,0) FROM CUSTFLAT

The SELECT statement invokes UNPACK, passing it the name of the field containing the packed data, the starting position and length (in bytes) of the packed data, and the number of decimal places to be used in the resulting data. This statement returns the unpacked data as shown in Figure 2.

http://www.mcpressonline.com/articles/images/2002/TechTip%20Table%20functionV3--03250501.png

Figure 2: Extract data with the UNPACK function.

Now that we have the UNPACK function to do the hard work for us, we can use a table function to make extracting data from the flat file much easier. The table function is similar to a view. It returns a table object that can be used within SQL statements and allows us to write the complex code used to extract the data--just once.

The following code generates a table function named GETCUSTF that extracts the customer number and name for all of the rows in CUSTFLAT:

CREATE FUNCTION GETCUSTF ()                                       
RETURNS TABLE(CUSTNO CHAR(7), CUSTNAM CHAR(30))                   
LANGUAGE SQL                                                      
READS SQL DATA                                                     
NO EXTERNAL ACTION                                                 
NOT DETERMINISTIC                                                      
DISALLOW PARALLEL                                                  
RETURN                                                             
SELECT UNPACK(CUSTFLAT,1,3,0), SUBSTR(CUSTFLAT,4,30) FROM CUSTFLAT

The table function GETCUSTF receives no parameters (or arguments) and returns two columns of data--the CUSTNO and CUSTNAM columns. The data for these two columns is provided by the SELECT statement at the end of the code. It should look familiar; it's exactly the same as the code used in the last example except that the columns appear in reverse order.

Once this function is created, it can be invoked with the following statement:

select * from TABLE (getcustf()) as CUSTFLAT  

The resulting data is shown in Figure 3.

http://www.mcpressonline.com/articles/images/2002/TechTip%20Table%20functionV3--03250502.png

Figure 3: The GETCUSTF table function yields these results.

Kevin Forsythe is the author of the new book SQL for eServer i5 and iSeries. He has over 18 years of experience working with the iSeries platform and its predecessors. He has been a member of the DMC team for the past nine years. Kevin's primary responsibility is providing iSeries education, but he also provides customers with project management, system design, analysis, and technical construction. In addition to his technical skills (RPG IV, CL, OS/400, SQL, FTP, Query, VB, Net.Data), Kevin possesses the ability to communicate new and complex concepts to his students. He has been the primary instructor for DMC's iSeries-based AS/Credentials training courses since 1997 and has authored courses such as Advanced ILE, SQL, Embedded SQL, Operations Navigator, and Intro to WebSphere Studio. An award-winning speaker, he has spoken at every COMMON Conference since the spring of 2000.

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: