Learn how to parse DB2 for i JSON using JSON_TABLE and JSON_TABLE_BINARY.
In my previous JSON tip, I introduced DB2's new ability to store and parse JSON data using SQL in DB2 for i. This tip continues the topic of JSON parsing by discussing the JSON_TABLE and JSON_TABLE_BINARY table functions and their ability to process JSON arrays.
If you're unfamiliar with JSON in DB2 for i, please review my prior TechTip as it discusses the IBM i prerequisites, the initial JSON setup, and the concept of casting JSON to BSON when storing JSON documents in DB2. Today's tip assumes you have some familiarity with the JSON_VAL scalar function and storing JSON data as BSON. Finally, note that the JSON features at this release are being called a technology preview and are therefore subject to change. So test carefully before using the JSON features in production.
Extracting Data Element Arrays
In the prior tip's JSON parsing example, the JSON document was simple so that the JSON_VAL scalar function could be used to extract the required data to build a single-row result set. However, what if you have a JSON document like the one below, describing donut variations with nested arrays for dough batters and toppings? IBM's answer is to use the JSON_TABLE table function. Similar to XMLTABLE, JSON_TABLE can extract and return a list of elements in tabular form.
In this example, the batter types will be extracted using the JSON_TABLE function. Keep in mind, as with XMLTABLE, sometimes you may need to process the JSON document multiple times in order to extract all of the array items in tabular form.
-- Sample JSON doc from
-- http://adobe.github.io/Spry/samples/data_region/JSONDataSetSample.html
SELECT *
FROM TABLE(SYSTOOLS.JSON_TABLE(
SYSTOOLS.JSON2BSON('
{
"id": "0001",
"type": "donut",
"name": "Cake",
"ppu": 0.55,
"batters":
{
"batter":
[
{ "id": "1001", "type": "Regular" },
{ "id": "1002", "type": "Chocolate" },
{ "id": "1003", "type": "Blueberry" },
{ "id": "1004", "type": "Devil''s Food" }
]
},
"topping":
[
{ "id": "5001", "type": "None" },
{ "id": "5002", "type": "Glazed" },
{ "id": "5005", "type": "Sugar" },
{ "id": "5007", "type": "Powdered Sugar" },
{ "id": "5006", "type": "Chocolate with Sprinkles" },
{ "id": "5003", "type": "Chocolate" },
{ "id": "5004", "type": "Maple" }
]
}'),'batters.batter.type','s:32')) Data
;
JSON_TABLE accepts the same three arguments as JSON_VAL: BSON data, the element to extract, and the resulting data type. The table function returns two columns: type and value. The results of the above query are shown here:
TYPE |
VALUE |
2 |
Regular |
2 |
Chocolate |
2 |
Blueberry |
2 |
Devil's Food |
The value column is, of course, the requested JSON element's value. The type column is a little bit more difficult to interpret (and at the time of this writing, I couldn't find any documentation on this table function). After some experimentation with JSON_TABLE, the following type values have been identified:
Type |
Description |
1 |
number (e.g., 0.123, 3.122e15) |
2 |
String |
3 |
object / array |
8 |
Boolean |
10 |
Null |
16 |
Integer |
To recap, the TYPE column will assist you in deciding which DB2 data type to use to store the element's value.
In this next example using the same JSON "donut data," the topping variations (elements id and type) will be extracted with the top level "donut" item information (type, name, ppu). Instead of using JSON_TABLE, this example will use JSON_TABLE_BINARY, which is similar to JSON_TABLE except its VALUE column returns BSON instead of VARCHAR.
WITH DONUT_DATA(JSON_INFO) AS (
SELECT * FROM (VALUES(SYSTOOLS.JSON2BSON('
{
"id": "0001",
"type": "donut",
"name": "Cake",
"ppu": 0.55,
"batters":
{
"batter":
[
{ "id": "1001", "type": "Regular" },
{ "id": "1002", "type": "Chocolate" },
{ "id": "1003", "type": "Blueberry" },
{ "id": "1004", "type": "Devil''s Food" }
]
},
"topping":
[
{ "id": "5001", "type": "None" },
{ "id": "5002", "type": "Glazed" },
{ "id": "5005", "type": "Sugar" },
{ "id": "5007", "type": "Powdered Sugar" },
{ "id": "5006", "type": "Chocolate with Sprinkles" },
{ "id": "5003", "type": "Chocolate" },
{ "id": "5004", "type": "Maple" }
]
}
'))) temp)
SELECT JSON_VAL(d.JSON_INFO,'type','s:32') AS Type,
JSON_VAL(d.JSON_INFO,'name','s:32') AS Name,
JSON_VAL(d.JSON_INFO,'ppu','f') AS PPU,
JSON_LEN(d.JSON_INFO,'topping') AS No_Toppings,
JSON_VAL(TOPPING_DATA.VALUE,'id','i') AS Topping_Id,
JSON_VAL(TOPPING_DATA.VALUE,'type','s:64') AS Topping_Type
FROM DONUT_DATA d
CROSS JOIN TABLE(
SYSTOOLS.JSON_TABLE_BINARY(d.JSON_INFO,'topping','s:64')) TOPPING_DATA
;
The query returns this result set:
Type |
Name |
PPU |
Topping_Id |
Topping_Type |
donut |
Cake |
0.55 |
5001 |
None |
donut |
Cake |
0.55 |
5002 |
Glazed |
donut |
Cake |
0.55 |
5005 |
Sugar |
donut |
Cake |
0.55 |
5007 |
Powdered Sugar |
donut |
Cake |
0.55 |
5006 |
Chocolate with Sprinkles |
donut |
Cake |
0.55 |
5003 |
Chocolate |
donut |
Cake |
0.55 |
5004 |
Maple |
Notice that JSON_TABLE_BINARY was passed the "topping" element (second argument), which is itself an array with each element in the array looking like this: { "id": "5002", "type": "Glazed" }. The table function will return one row for each element in the array in BSON format. Since the VALUE column contains BSON, the JSON_VAL scalar function can be used to extract individual data elements.
You may have noticed the result type parameter passed to the JSON_TABLE and JSON_TABLE_BINARY functions includes a type and a string length (e.g., 's:64'). The length is important as it instructs the table function on how much space to allocate for a string. In the DB2 examples I found online, the JSON_VAL function also required the length. When investigating JSON_VAL on DB2 for i, I found that while the length can be specified in DB2 for i, it is currently ignored.
An additional useful JSON array function is JSON_LEN. JSON_LEN accepts BSON data and an element and returns the number of elements in the requested array. Assuming that global variable ADVWORKS.JSON_DONUT is defined as a BLOB(64K) and contains the BSON version of the JSON donut data illustrated above:
VALUES (
SYSTOOLS.JSON_LEN(ADVWORKS.JSON_DONUT,'batters.batter'),
SYSTOOLS.JSON_LEN(ADVWORKS.JSON_DONUT,'topping')
);
This example will return integer values of four and seven, because there are four batters and seven toppings defined in the JSON data.
In conclusion, use JSON_TABLE for extracting single primitive elements (text and numbers) from an array. JSON_TABLE_BINARY can be used to extract the entire array element, and then JSON_VAL can be used to extract the individual elements.
References
TechTip: Store and Parse JSON Data Natively with DB2 for i
IBM DB2 for i: JSON Store Technology Preview—A 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
LATEST COMMENTS
MC Press Online