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:
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
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:
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:
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.
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:
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:
The resulting data is shown in Figure 3.
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.
LATEST COMMENTS
MC Press Online