TechTip: BLOBs Keep PDF, XLS, and Other Reports Safe in DB2, Part 2

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

In the first part of this TechTip series, I explained what a BLOB is and how it works. Now, I'll provide you with the tools to use this little-known and underestimated DB2 feature.

 

In the previous TechTip, I covered the BLOB basics, so now it's time to implement the archiving and retrieving operations in a reusable, yet simple, way.

 

First Things First; Let's Archive Something

I'll start with the archiving operation. If you remember the BLOB_IN sample program from the previous TechTip, it expected an ID, a file type, a comment and, of course, the file's full name and path in order to store it on a DB2 table (called REPORTS in this case). The Snd_File_To_Archive procedure expects the same input parameters, except for the ID, which will be the procedure's output. This way, the calling program doesn't have to generate a unique ID; the procedure takes care of that and returns the ID to the calling program, thus providing a simpler-to-use tool. If the returned ID is zero, it means the operation was not successful. It's a quick and easy way of having some control over the whole process without complicating things. Here's the procedure's complete source code:

 

     PSnd_File_To_Archive...                                

     P                 B                   EXPORT          

     DSnd_File_To_Archive...                                

     D                 PI             7 0                  

     * Input Parms                                        

     D P_FileName                 255A   Value            

     D P_Type                       10A   Value            

     D P_Comments                 255A   Value            

                                                            

     D W_ID           S             7 0 Inz(*Zeros)      

                                                            

     D W_File_In       S                   SQLTYPE(BLOB_FILE)

                                                            

                                                            

     // Store an object into the blob table                

     /FREE                                                  

       EXEC SQL   Select Max(Rpt_Id) + 1                    

                   Into :W_Id                              

                   From RptArchive/Reports;                

       If W_Id = *Zeros;                                    

         W_Id = 1;                                      

       EndIf;                                            

       W_File_In_FO   = SQFRD;                          

       W_File_In_NAME = %Trim(P_FileName);              

       W_File_In_NL   = %len(%trimr(W_File_In_NAME));    

                                                        

       EXEC SQL   Insert Into RptArchive/Reports        

                         Values (:W_ID, :P_Type, NOW(),  

                                 :P_Comments, :W_File_In);

                                                                

       // If the insert operation was successful, return the ID    

       If SQLCod = *Zeros;       

         Return W_Id;                                   

       Else;                                   

     // otherwise, return zeros to indicate something went wrong

         Return *Zeros;                     

       EndIf;                                                                                                   

     /END-FREE                                          

     PSnd_File_To_Archive...                            

     P                 E                                

 

Most of the code should be familiar because this procedure is heavily based on the first TechTip's BLOB_IN sample program. The only part that is really new is the SQL statement used to generate the unique ID. This ID is what the procedure returns if the "archiving" operation is successful. If it fails, then a zero is returned so that the calling program can proceed accordingly.

 

Well Now, What Was the Number of the File You Were Looking For?

 

To retrieve the file from the "Reports" table, I've created the Rtv_File_From_Archive procedure. Here's the procedure's complete source code:

       **************************************************************************

       * Store an IFS file into the BLOB table and return an unique ID          

       **************************************************************************

     PRtv_File_From_Archive...                                                

     P                 B                   EXPORT                              

     DRtv_File_From_Archive...                                                

     D                 PI             1A                                      

       * Input Parms                                                            

     D P_Id                          7 0 Value                              

     D P_FileName                 255A   Value                              

                                                                                

     D W_File_Out     S                  SQLTYPE(BLOB_FILE)                  

     D W_Success       S             1A                                      

                                                                                

       // Retrieve an object from the blob table                                

                                                                                

       /FREE                                                                    

       W_Sucess = '1';                                                        

       W_File_Out_FO   = SQFOVR;                                              

       W_File_Out_NAME = %Trim(P_FileName);                                    

       W_File_Out_NL   = %Len(%TrimR(P_FileName));  

                                                    

       EXEC SQL   Select Rpt_File1                  

                   Into :W_File_Out                

                   From RptArchive/Reports        

                  Where Rpt_Id = :P_Id;          

                                                    

       If SQLCod <> *Zeros;                        

         W_Success = '0';                            

       EndIf;                                      

     Return W_Success;    

                                                    

     /END-FREE                                    

     PRtv_File_From_Archive...                      

     P                 E                            

 

Again, the code should look familiar to those who read the first TechTip: this procedure was based on the BLOB_OUT sample program. It receives the unique ID of the file to be retrieved, writes it to the IFS path and file name indicated on the P_FileName parameter, and returns a success (or failure) indicator.

 

With these two procedures, you should be able to archive and retrieve files from the Reports DB2 table. Cool, isn't it?

 

Every Piece of Code Is Easier to Understand with an Example…or Two!

To consolidate all this information, let's review two very simple examples of these procedures in action. Let's begin by archiving a file with sample program TST_SND:

 

     *                                                            

     * This is a simple test program to demonstrate how to use the

     * Snd_File_To_Archive procedure                              

     *                                                            

     * Prototype definition                                      

     /Copy QCPYLESRC,DBMBLOB_PR                                  

     *                                                            

     * Function Parms                                              

     D P_FileName     S           255A   Inz                    

     D P_Type         S             10A   Inz                    

     D P_Comments     S           255A   Inz                    

                                                                    

     * Work variables                                            

     D W_ID           S             7 0 Inz                    

                                                                  

     /FREE                                                        

       P_FileName = '/Reports/Test.PDF';                          

       P_Type     = 'PDF';                                        

       P_Comments = 'Just a PDF test report';                      

 

     W_ID = Snd_File_To_Archive(P_FileName : P_Type : P_Comments);

                                                                  

     Dsply %Char(W_ID);                                          

                                                                  

     *InLr = *On;                                                

     /END-FREE                                                    

 

Not much to it, really. The program prepares the procedure's parameters and invokes it, storing the returned ID in the W_ID variable. In a real-life situation, you'd store this ID somewhere (and use more meaningful comments) to be able to find the archived file later.

 

Sample program TST_RTV provides an example of how the file can be retrieved:

 

     *                                                            

     * This is a simple test program to demonstrate how to use the

     * Rtv_File_From_Archive procedure                            

     *                                                            

     * Prototype definition                                      

     /Copy QCPYLESRC,DBMBLOB_PR                                  

     *                                                            

     * Function Parms                                            

     D P_ID           S             7 0 Inz                    

     D P_FileName     S           255A   Inz                    

                                                                  

     * Work variables                                            

     D W_OK           S             1A   Inz                    

                                                                    

     /FREE                                                        

       P_Id = 1;                                                  

       P_FileName = '/Reports/Test_Retrieved.PDF';                

                                                                  

       W_OK = Rtv_File_From_Archive(P_Id : P_FileName);            

                                                  

       If W_Ok = '1';                            

         Dsply 'File Successfully retrieved';      

       Else;                                      

         Dsply 'An error occurred';              

       EndIf;                                    

                                                  

       *InLr = *On;                              

     /END-FREE

 

Just like in the previous example, all that's required is to fill in the procedure's parameters, invoke it, and do something with the return code. In this case, if the procedure returns '1', then everything went according to plan. The file still exists on the Reports table, but a copy of it was now created on the path specified in the P_FileName parameters.

 

Final Thoughts

Note that the file and library names of the table with the BLOB column (RPTARCHIVE/REPORTS) are hardcoded on the SQL statements of both procedures. There are ways to circumvent this limitation, but I prefer to keep things simple! If you really want to integrate this into your application (in order to use your application's library and/or adjust the file name to follow your company's naming convention), remember to modify the SQL statements of the procedures to reflect those changes.

 

Be sure to copy the Reports folder from the downloadable source code zip file to your IFS's root. You'll also find a file with compilation instructions in the zip, but if you have any questions, remarks, or suggestions, feel free to contact me!

 

In the third and final part of this series, I'll revisit some older articles, providing more complex usage examples of the procedures presented here.

Rafael Victoria-Pereira

Rafael Victória-Pereira has more than 20 years of IBM i experience as a programmer, analyst, and manager. Over that period, he has been an active voice in the IBM i community, encouraging and helping programmers transition to ILE and free-format RPG. Rafael has written more than 100 technical articles about topics ranging from interfaces (the topic for his first book, Flexible Input, Dazzling Output with IBM i) to modern RPG and SQL in his popular RPG Academy and SQL 101 series on mcpressonline.com and in his books Evolve Your RPG Coding and SQL for IBM i: A Database Modernization Guide. Rafael writes in an easy-to-read, practical style that is highly popular with his audience of IBM technology professionals.

Rafael is the Deputy IT Director - Infrastructures and Services at the Luis Simões Group in Portugal. His areas of expertise include programming in the IBM i native languages (RPG, CL, and DB2 SQL) and in "modern" programming languages, such as Java, C#, and Python, as well as project management and consultancy.


MC Press books written by Rafael Victória-Pereira available now on the MC Press Bookstore.

Evolve Your RPG Coding: Move from OPM to ILE...and Beyond Evolve Your RPG Coding: Move from OPM to ILE...and Beyond
Transition to modern RPG programming with this step-by-step guide through ILE and free-format RPG, SQL, and modernization techniques.
List Price $79.95

Now On Sale

Flexible Input, Dazzling Output with IBM i Flexible Input, Dazzling Output with IBM i
Uncover easier, more flexible ways to get data into your system, plus some methods for exporting and presenting the vital business data it contains.
List Price $79.95

Now On Sale

SQL for IBM i: A Database Modernization Guide SQL for IBM i: A Database Modernization Guide
Learn how to use SQL’s capabilities to modernize and enhance your IBM i database.
List Price $79.95

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • 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.

  • 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

  • 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: