13
Wed, Nov
5 New Articles

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

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

Ever had a user asking for a report you couldn't generate again because it was a "snapshot" of your database at a certain time? Here's how to fix that!

 

This TechTip will tell you all you need to know about the BLOB. No, we're not talking about the 1958 Steve McQueen movie or the Marvel villain. We're going to revisit a fairly old concept, with a new twist: the Binary Large OBject. I'll explain how and why you can use it in the context of iSeries-generated PDFs and charts. Read on to find out more.

 

A BLOB is, basically, a way to store a non-native object on a DB2 database. By non-native object, I mean a file, such as a PDF, a spreadsheet, or a web page. This can be especially useful when your application generates reports in these (or other) formats and you need to retrieve them quickly, without having to produce the report all over again. In fact, if your report is a "snapshot" of a certain moment (like the end of the month or quarter, for instance), it might be hard to produce the exact same report.

 

As you might have guessed by now, the DB2 implementation of the BLOB concept consists of a kind of column on a database table. I say "kind of" because you cannot actually query this column; all you'll see is a pointer reference. In order to access the content, you need to extract it to the IFS.

 

Let's start by creating a table with some information to help us identify what's inside each BLOB:

 

CREATE TABLE RPTARCHIVE/REPORTS

 

(RPT_ID DECIMAL (7 , 0)

 

, RPT_TYPE CHAR (10 )

 

, RPT_TIME TIMESTAMP

 

, RPT_RMK CHAR (200 )

 

, RPT_FILE1 BLOB (500K )

 

, CONSTRAINT PK_RPT_ID UNIQUE (RPT_ID))

 

Rpt_Id is the unique identifier of the stored file, and Rpt_Type and Rpt_Rmk (short for remark) will help you identify the content without having to extract it to the IFS. Finally, I've created the BLOB itself (Rpt_File1) with 500K. This is something you need to handle with care, because the BLOB size is not dynamic or dependant on the content size. In other words, each line of this table will occupy a little of 500K of disk space, regardless of the file size contained within the BLOB. Another detail that might be important for the development management of this table is that it cannot be created with a DDS. Currently, there's no way to create a BLOB-type column using DDS keywords.

 

Now that we have our "report archive," it's time to store something on it. In order to do that, you need to use a special data structure composed of the following fields:

 

  • File Name Length (10u 0)The size of the complete file and path name in characters
  • Data Length (10u 0)The size of the file (an optional parameter)
  • File Option (10u 0)The operation you want to execute (I'll explain this further on)
  • File Name (255A )The complete path and file name

 

The Blob_In sample program stores the PDF file /Reports/Test.PDF into the REPORTS table:

 

     D Rpt_ID         S             7 0 Inz(*Zeros)

 

     D Rpt_Type       S             10   Inz(*Blanks)

 

     D Rpt_Rmk         S           255   Inz(*Blanks)

 

 

     D File_In         s                   SQLTYPE(BLOB_FILE)

 

 

     * The SQLTYPE(BLOB_FILE) definition will be converted by the compiler

 

     * into the following data structure:

 

     D*File_In         DS

 

     D*File_In_NL                   10U 0

 

     D*File_In_DL                   10U 0

 

     D*File_In_FO                   10U 0

 

     D*File_In_NAME                 255A

 

 

 

     // Store an object into the blob table

 

     /FREE

 

       Rpt_ID = 1;

 

       Rpt_Type = 'PDF';

 

       Rpt_Rmk = 'Just a PDF test report';

 

       File_In_FO   = SQFRD;

 

       File_In_NAME = '/Reports/Test.PDF';

 

       File_In_NL   = %len(%trimr(File_In_NAME));

 

 

       EXEC SQL   Insert Into RptArchive/Reports

 

                         Values (:Rpt_ID, :Rpt_Type, NOW(),

 

                                :Rpt_Rmk , :File_In);

 

 

 

       *InLr = *On;

 

     /END-FREE

 

Here, I'm passing all the relevant information into the special data structure and executing a simple INSERT statement. Note that I didn't actually define the File_In data structure; I defined a SQLTYPE(BLOB_File) field, which the compiler converts into the special data structure I mentioned above.

 

If you query the REPORTS table, you'll see the newly inserted record. As I mentioned before, you can't actually see the file inside the BLOB; you will see a pointer instead. That's why I added the Rpt_Type and Rpt_Remark columns to the table.

 

Now, let's retrieve the file from the archive, with the BLOB_OUT sample program: 

 

     D Rpt_ID         S             7 0 Inz(*Zeros)

 

 

     D File_Out       s                   SQLTYPE(BLOB_FILE)

 

 

     * The SQLTYPE(BLOB_FILE) definition will be converted by the compiler

 

     * into the following data structure:

 

     D*File_Out       DS

 

     D*File_Out_NL                   10U 0

 

     D*File_Out_DL                   10U 0

 

     D*File_Out_FO                   10U 0

 

     D*File_Out_NAME               255A

 

 

 

     // Retrieve an object from the blob table

 

 

     /FREE

 

       Rpt_ID = 1;

 

       File_Out_FO   = SQFOVR;

 

       File_Out_NAME = '/Reports/Test_Out.PDF';

 

       File_Out_NL   = %Len(%TrimR(File_Out_NAME));

 

 

       EXEC SQL   Select Rpt_File1

 

                   Into :File_Out

 

                   From RptArchive/Reports

 

                   Where Rpt_Id = :Rpt_Id;

 

 

       *InLr = *On;

 

 

     /END-FREE

 

Again, I'm passing all the relevant information to the special data structure in order to retrieve the file with a SELECT statement. Other than the SQL statement used, the big difference between the two programs is the file option I used (…_FO field of the special data structure). In the first program, it was SQFRD, which tells the program I'm using the file in "read mode"; in the second program, I wanted to write the file to the IFS, overwriting it if it existed. For that I chose SQFOVR. Here's the complete list of file options available:

 

  • SQFRDOpen IFS file for reading only
  • SQFCRTCreate IFS file if it doesn't exist, and open for writing
  • SQFOVRCreate IFS file if it doesn't exist, overwrite it if it does exist, and open for writing
  • SQFAPPAppend data to the end of an existing IFS file

 

In the second part of this TechTip, I'll walk you through the creation of simplified store/retrieve procedures that can be used in both RPG and SQL!

 

 

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

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