13
Wed, Nov
5 New Articles

TechTip: BLOBs: Don't Run! Embrace Them with RPG!

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

There's no need to be afraid. Learn how to use RPG to load and extract binary data to and from DB2 BLOB columns.

Written by Gene Cobb

While vampires and zombies are all the rage these days, menacing invaders from outer space used to be the fright night monster du jour. Remember The Blob starring Steve McQueen? While this terrifying, bubbly alien may conjure up images of panic-stricken people running frantically through the streets, the database BLOB is actually something that should be…well…embraced!

 

Don't worry. The database BLOB bears little resemblance to the giant glob of goo that terrorized a rural Pennsylvania town and devoured its victims. The database version is a built-in DB2 data type that allows you to store vast amounts of unstructured data as a single entity in a column. In fact, the LOB portion of the name stands for Large Object. There are actually three different types of LOB data types in DB2:

  • CLOB (Character Large Object)Large character string data type that is compatible with CHAR and VARCHAR types
  • DBCLOB (Double-Byte Character Large Object)Large double-byte character string data type that is compatible with GRAPHIC and VARGRAPHIC types
  • BLOB (Binary Large Object)Binary data type. Ideal for storing scanned documents, digital images, PDF documents, Word documents, XLS spreadsheets, etc.

 

In this TechTip, we focus on the BLOB, a data type that gives you a centralized, secure place to store your PDF files, your presentations, even your important spreadsheets and documents!

 

Think about that for a moment. Instead of storing these types of binary files on multiple PCs throughout your network, a shared PC/file server, or even the Integrated File System (IFS) of the IBM i, you can tuck them neatly away in your DB2 for i tables! Want to tidy things up and get organized? Store the sales invoice image in the same row as the sales transaction! Have a bunch of employee resumes in PDF format? Keep them in the Human Resources table along with all their other employee personnel information. Still not convinced? Then consider these additional advantages:

  • Ease of accessUse SQL selection (WHERE clause) to easily locate and retrieve a particular image or document based on other columns in the table, such as customer name or order date.
  • SecurityIn addition to IBM i object-level security, leverage the power of SQL to implement row-level security using SQL views to restrict row access to certain users. In addition, by using a combination of views and user-defined functions (UDFs), you can even restrict user access to specific columns. For more information on these techniques, see the article titled "Using SQL Views and Stored Procedures to control Security with DB2 Web Query" at this URL.
  • Text searchingUse the IBM i OmniFind product to perform searching of text within the documents stored in the BLOB. More information can be found here.
  • Simplified backup and recovery—Saving the table means you save both the data and the stored documents! Ditto on the restore!
  • One version of the truth—A BLOB provides a centralized, secure location to store the master copies of documents. Eliminate the common problem of multiple versions of the truth floating around within your organization.

 

Creating a Table with a BLOB Column

Now that you're a BLOB believer, the first step is to create a table with a BLOB column. Because there is no DDS support for LOB data types, this can be done only by using SQL Data Definition Language (DDL). In the following example, you create a three-column table to hold the document identifier (DOCID, which can be used as a unique or primary key), the document title (DOCTITLE), and the binary document itself (DOCBLOB, the BLOB column):

 

CREATE TABLE QGPL/DOCREPOS (                        

DOCID ROWID GENERATED ALWAYS,

DOCTITLE CHAR(200) DEFAULT NULL ,      

DOCBLOB BLOB(524288000) DEFAULT NULL)

Using RPG to Load Binary Files into BLOB Columns

Now that the table has been created, you're ready to insert rows and load your documents into the BLOB. An easy way to set the stage for this is to first move your documents to a holding directory on the IFS. From there, they can be loaded directly into the table. This process is illustrated in Figure 1 below, where the files are first copied to the IFS directory /home/2011_Data/ and then loaded into the table.

 

120712CobbFig1                    

Figure 1: Load documents from IFS into the BLOB.


So how do you do this? Does moving data into LOB columns mean you have to write utility routines, code to complex APIs, and create a bunch of host variables? Nope! A simple RPG program will do the trick! The following SQLRGPLE example reveals just how easy it is.

 

D   MYFILE        S                   SQLTYPE(BLOB_FILE)

D   SQL_FILE_READ...

D                 c                   const(2)
D SQL_FILE_OVERWRITE...

D                 c                   const(16)

d newDocID        s             9B 0

d newDocTitle     s             200a

/free

   newDocTitle = '2011 Financials   Spreadsheet';

   myfile_fo = SQL_FILE_READ;

   myfile_name =   '/home/2011_Data/Financials_2011.xls';

   myfile_nl = %len(%trimr(myfile_name));

   exec SQL

     insert into QGPL/DOCREPOS (docTitle, docBLOB)

     values(:newDocTitle, :myfile);

   return;

/end-free

 

In this program, you assign the document title, open/read the file located on the IFS, provide the name and length of the location of that file, and finally issue the SQL insert statement to add the row to the table.

 

To understand this better, let's examine what happens during the SQL precompiler process. Notice the first line in the example program above (the BLOB_FILE data type definition for the variable MYFILE). This variable is translated by the SQL precompiler into the following data structure:


D MYFILE           DS
D MYFILE_NL                     10U 0
D MYFILE_DL                     10U 0
D MYFILE_FO                     10U 0
D MYFILE_NAME                   255A

                    

 

Four special suffixes are appended by the precompiler to the variable name to form four additional fields. These are referred to as LOB file reference variables, and they can be used in your programs to facilitate the movement of LOB values to and from the table:

 

_NLLength of the file name

_DLLength of the data

_FOFile option. Valid values are:

  • 2 (SQL_FILE_READ) – Indicates that is a regular file that can be opened, read, and closed.
  • 8 (SQL_FILE_CREATE) - Creates a new file. If the file already exists, an error message is returned.
  • 16 (SQL_FILE_OVERWRITE) – Creates a new file. If the file already exists, it is overwritten with the new data
  • 32 (SQL_FILE_APPEND)

_NAMEThe name of the file (the actual full path or location on the IFS)

To instruct the program to open and read a file on the IFS, you simply set the file option variable to a value of 2 (for SQL_FILE_READ). Next, supply the name of the file's location on IFS, as well as the length of this name. Finally, issue the INSERT statement to add a new row to the table. During the insert process, the referenced file in the IFS will be copied into the BLOB column. So easy!

Using RPG to Extract Binary Files from BLOB Columns

So now the binary data is safely tucked away in the BLOB. What happens in the future when you need to access the data in the BLOB? You simply write the file back out of the IFS. Just use the appropriate file options to instruct the program to go the other direction. The following RPG example does just that. 

D   MYFILE         S                   SQLTYPE(BLOB_FILE)        

D   SQL_FILE_OVERWRITE...                                    

D                 c                   const(16)                  

/free                                                            

   myfile_fo = SQL_FILE_OVERWRITE;                              

   myfile_name =   '/home/2011_Data/Financials_2011.xls';          

   myfile_nl =   %len(%trimr(myfile_name));                          

   exec SQL                                                        

     SELECT docblob                                                

     INTO :myfile                                                  

     FROM QGPL/DOCREPOS                                          

     WHERE DocTitle = '2011 Financials   Spreadsheet';            

   return;                                                        

/end-free                                                        

 

In this example, you set the file option variable to SQL_FILE_OVERWRITE, assign the value and length of the name of the target file, and finally specify an SQL SELECT to find the row with the binary data you're looking for. When the SQL statement is executed, it creates a new file on the IFS named /home/2011_Data/Financials_2011.xls. If that file happens to already exist in that directory, it's overwritten with the data from the BLOB column. Hmmm…so in effect the database BLOB will devour the existing spreadsheet. On second thought, maybe it does have some of the same characteristics as "The Blob"! Run for your lives!!

Summary

LOB columns are a great way to store large amounts of unstructured data, whether they're in textual or binary format. They provide a mechanism for storing these types of data sources in an organized and secure manner; and by using the file reference variables available in the SQL precompiler, it's extremely easy to load and extract this data to and from LOB columns. I strongly encourage you to give BLOBs a try in your shop. However, if custodians start mysteriously disappearing…

 

Gene Cobb

Gene Cobb is a DB2 for i5/OS Technology Specialist in IBM's ISV Business Strategy & Enablement for System i group. He has worked on IBM midrange systems since 1988, including over 10 years in the IBM Client Technology Center (now known as IBM Systems and Technology Group Lab Services). While in Lab Services, he assisted customers with application design and development using RPG, DB2 for i5/OS, CallPath/400, and Lotus Domino. His current responsibilities include providing consulting services to System i developers, with a special emphasis in application and database modernization. He can be reached at This email address is being protected from spambots. You need JavaScript enabled to view it..

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: