29
Fri, Nov
0 New Articles

TechTip: Store and Parse JSON Data Natively with DB2 for i

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

Learn how the latest DB2 for i features can reduce development time when interacting with the popular JSON data format.

 

In my prior tip about using JSON with DB2 for i, I articulated a method of accessing JSON with SQL by use of Java external user-defined functions (UDFs) that convert JSON to XML and XML to JSON. Starting in IBM i 7.1 TR10 (Database Group PTF Level 34) and IBM i 7.2 TR2 (Database Group PTF Level 5), IBM has added native JSON support to the DB2 for i database engine. Keep in mind that, at this first release, the JSON support is still considered a "technology preview," so be sure to test any JSON implementations carefully before using them in production. Also, based on available documentation, some of these features and JSON functions are not yet advertised by IBM for the IBM i and may be subject to change.

The new JSON support comes in the form of a command-line processor, a Java API, and SQL functions. In this tip, I will discuss the SQL functions that can be used to store and parse JSON. Creating a JSON document from relational data will not be discussed at this time as it is not available via the SQL interface, but interested readers can review the Java API for information on how to do this (see the references section for where to learn more about the command line and Java API features).

Why JSON?

JSON is a popular data format, with many modern APIs requiring JSON input and returning JSON output. Having easy-to-learn tools in the toolbox to work with JSON is definitely a boon to developers. You can learn more about JSON at JSON.org.

Getting Started

In order to make the JSON SQL functions accessible on your IBM i partition, the following operation must be executed once within QSHELL:

/QIBM/ProdData/OS/SQLLIB/bin/db2nosql -setup enable

This step will install various JSON-related SQL functions in the schema SYSTOOLS. To use these functions, be sure to qualify them with the SYSTOOLS schema or ensure your SQL path includes SYSTOOLS by using the SET PATH statement.

Understanding JSON (CLOB) and BSON (BLOB)

It's important to note that, when you're using the native JSON support, DB2 for i will store JSON (character) data in a BLOB (binary) column in a special format IBM calls BSON. So if you're building a table to store a JSON document and intend to use the native DB2 support for storage and retrieval, choose the BLOB data type for the JSON column, rather than a CLOB.

There are new scalar functions called BSON2JSON and JSON2BSON that are used to cast JSON data to BSON and vice versa (more about this in a moment). Note the current maximum size of a JSON document is 16MB (far less than the DB2 for i 2GB large object limit).

Storing JSON Data in a Table

Say you intend to build a DB2 table that stores information about flat files that are stored in Microsoft's OneDrive (formerly SkyDrive) cloud service. Further, a local copy of each OneDrive file is kept on the IFS of your IBM i. Moreover, information about each file is supplied by OneDrive as a JSON document. The table definition may look something like this:

CREATE TABLE MYLIB.FILE_INFO (

FILE_NAME     VARCHAR(64) NOT NULL,

IFS_COPY_PATH VARCHAR(256) NOT NULL,

JSON_INFO     BLOB(32K)   NOT NULL)

Data, including a JSON document, can be inserted into this simple table as follows:

-- OneDrive Sample JSON Object (abridged)

-- https://msdn.microsoft.com/en-us/library/office/dn631834.aspx

INSERT INTO MYLIB.FILE_INFO

SELECT 'Processing.docx','/OneDrive/Processing.docx',

SYSTOOLS.JSON2BSON('{

   "data": [

     {

         "id": "file.22688711f5410e6c.22688711F5410E6C!942",

         "from": {

           "name": "Mike Sansoterra",

           "id": "22688711f5410e6c"

         },

         "name": "Processing.docx",

         "description": null,

         "parent_id": "folder.22688711f5410e6c.22688711F5410E6C!479",

         "size": 12692,

         "comments_count": 0,

         "comments_enabled": true,

         "is_embeddable": false,

         "type": "file",

         "shared_with": {

           "access": "Everyone (public)"

         },

         "created_time": "2011-10-12T23:18:23+0000",

         "updated_time": "2011-10-12T23:18:23+0000"

     }

   ]

}

')

FROM SYSIBM.SYSDUMMY1

Notice that the JSON2BSON function will validate the JSON data and CAST it to the binary format (BSON) that DB2 requires for internal storage and processing. Once the JSON data is in the BLOB column, it will no longer be human-readable. To CAST the JSON data back from BSON to character, use the BSON2JSON function as shown here:

SELECT FILE_NAME,SYSTOOLS.BSON2JSON(JSON_INFO) AS JSON_INFO

FROM MYLIB.FILE_INFO

For the record, instead of being hard-coded as in the example, the JSON data from OneDrive would normally be retrieved via an API call. When working in DB2, this is most likely done with the HTTPGETCLOB function, which can be used to retrieve the file information from the Microsoft cloud-based REST API.

Validating BSON Data

Please note you can dump anything into the BLOB column intended to hold JSON data, but don't expect the DB2 for i JSON functions to work if you do not convert the content to BSON first! Using the JSON functions against invalid data will generate an error that looks something like this:

SQL State: 22546

Vendor Code: -171

Message: [SQL0171] Argument 11 of function JSONVAL not valid.

If you suspect something is amiss with your JSON data, you can test the validity of a particular column using the BSON_VALIDATE function. This query returns all rows where column JSON_INFO does not contain valid BSON information:

SELECT *

FROM MYLIB.FILE_INFO

WHERE SYSTOOLS.BSON_VALIDATE(JSON_INFO)=0 /* 1=Valid 0=Invalid */

Extracting Elements from JSON Data

The JSON_VAL scalar function is used to extract individual elements from a JSON document. It accepts three arguments: a BLOB (BSON) column or variable, a path to the desired element, and a result data type (i.e., the DB2 data type to use when extracting the JSON data). Valid values for the result data type argument are shown in the following table:

Result Type     Function Return Type

'n'                     DECFLOAT(34)

'i'                      INTEGER        

'l'                      BIGINT

'f'                      DOUBLE         

'd'                     DATE  

'ts'                    TIMESTAMP   

't'                      TIME   

's'                     VARCHAR

Consider the following query that extracts elements from the JSON_INFO column in the sample FILE_INFO table (refer to the sample INSERT statement to view the JSON doc):

SELECT JSON_VAL(JSON_INFO,'data.id','s') AS Id,

       JSON_VAL(JSON_INFO,'data.name','s') AS FileName,

       JSON_VAL(JSON_INFO,'data.from.name','s') AS FromName,

       JSON_VAL(JSON_INFO,'data.shared_with.access','s') AS Access,

       JSON_VAL(JSON_INFO,'data.size','l') AS Size,

       TIMESTAMP(LEFT(REPLACE(

       JSON_VAL(JSON_INFO,'data.created_time','s')

       ,'T',' '),19)) AS Created_Time -- Timestamp format doesn't work

FROM MYLIB.FILE_INFO

WHERE JSON_VAL(JSON_INFO,'data.name','s')='Processing.docx'

The above query returns the following:

ID

FILENAME

FROMNAME

ACCESS

SIZE

CREATED_TIME

file.22688711f5410e6c.22688711F5410E6C!942

Processing.docx

Mike Sansoterra

Everyone (public)

12692

2011-10-12 23:18:23.000000

To understand how JSON_VAL works, consider the first column expression of the query. JSON_VAL(JSON_INFO,'data.id','s')is used to extract element data.id from the JSON data stored in column JSON_INFO and return the data type as a string. The data type DB2 assigns for a string is VARCHAR(2046). In other versions of DB2, a length can be specified (e.g., s:32), but DB2 for i currently doesn't appear to support this (but this may be a bug).

For a second example, expression JSON_VAL(JSON_INFO,'data.size','l') extracts the size element and returns it as a BIGINT data type.

You may have noticed in the query that I used some trickery to extract the created_time as a string and then convert it to a DB2 timestamp. The timestamp specified in the JSON document is the ISO 8601 format, but JSON_VAL doesn't seem to accept it; in fact, I couldn't get the timestamp result type (ts) to work at all after trying several different formats. Perhaps IBM is still work on this or I need some documentation!

What About Arrays?

The previous JSON parsing example is somewhat simple in that all of the data can be extracted in a single row. In the next TechTip, I will introduce the JSON_TABLE and JSON_TABLE_BINARY table functions, which can be used to extract array elements as rows in a result set.

Jamming with JSON

DB2 for i now includes the ability to store and parse JSON documents. IBM is doing a great job; it used to be Microsoft SQL Server would get new features long before IBM i. I've been pleased to see that features like row and column access (RCAC) security and JSON are only in preview with SQL Server 2016 (and in Azure). Great job, IBM! Because JSON is a popular format, especially in REST APIs, it behooves the IBM i developer to leverage the JSON processing capabilities possessed by DB2 for i. Finally, when coupled with the DB2 HTTP functions, it becomes a cinch to contact a JSON REST service in real time, return the results, and parse the data in just a few SQL statements.

References

IBM DB2 for i: JSON Store Technology PreviewA comprehensive overview of the JSON features available for IBM i

Four-Part Series on DB2 JSON capabilities (Note: not all of the described JSON capabilities are available in DB2 for i. Article 3 of this series describes the Java API that can be used to compose JSON documents.)

TechTip: JSON and XML Conversion in DB2 for i


TechTip: Check Out the New DB2 for i HTTP Functions

Michael Sansoterra is a DBA for Broadway Systems in Grand Rapids, Michigan. He can be contacted 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: