Use the java-json library to easily convert between XML and JSON formats.
As I noted in my article on SOA and REST, JavaScript Object Notation (JSON) is an important data format in today's world of RESTful service offerings. Whether your apps are publishing or consuming data, you may be asked to work with JSON. This tip offers an "el cheapo" technique on how to transform JSON to XML and vice versa, because XML is easy to work with in the RPG ILE and DB2 for i environment.
Many REST services offer XML and JSON data formats, but as of late I've noticed many of these services offering only JSON. With JSON, the world is good if you're a JavaScript developer but not so good if you're using a language that doesn't know anything about JSON processing.
Say for instance you're browsing through Google's JSON developer's guide and you find an image search REST API you want to incorporate into your application using the HTTPGETCLOB function:
SELECT data FROM
(VALUES(SYSTOOLS.HTTPGETCLOB
('https://ajax.googleapis.com/ajax/services/search/images?v=1.0&;q=fuzzy%20monkey',''))) WS(data);
Accessing this Google API will only get you a nice JSON response (shown below), but what does DB2 for i or even RPG know about JSON?
{
"responseData":{
"results":[
{
"GsearchResultClass":"GimageSearch",
"width":"1152",
"height":"864",
"imageId":"ANd9GcQQigy-U6KTXke82n5hma5qvFM2UyVnkGtJme6pkZgl_1GYM--Yb90oqnOJ",
"tbWidth":"150",
"tbHeight":"113",
"unescapedUrl":"http://www.blirk.net/wallpapers/1152x864/fuzzy-monkey-1.jpg",
"url":"http://www.blirk.net/wallpapers/1152x864/fuzzy-monkey-1.jpg",
"visibleUrl":"stackoverflow.com",
"title":"\u003cb\u003efuzzy\u003c/b\u003e-\u003cb\u003emonkey
\u003c/b\u003e-1.jpg",
"titleNoFormatting":"fuzzy-monkey-1.jpg",
"originalContextUrl":"http://stackoverflow.com/questions/17773949/
rails-best-way-to-extract-values-from-response-hash",
"content":"\u003cb\u003efuzzy\u003c/b\u003e-\u003cb\u003emonkey\u003c/b\u003e-1.jpg",
"contentNoFormatting":"fuzzy-monkey-1.jpg",
"tbUrl":"http://t1.gstatic.com/images?q\u003dtbn:ANd9GcQQigy-
U6KTXke82n5hma5qvFM2UyVnkGtJme6pkZgl_1GYM--Yb90oqnOJ"
},
...more data...
],
"cursor":{
"resultCount":"2,760,000",
"pages":[
{
"start":"0",
"label":1
},
...more data...
],
"estimatedResultCount":"2760000",
"currentPageIndex":0,
"moreResultsUrl":"http://www.google.com/images?oe\u003dutf8\u0026ie\u003dutf8\u0026source\u003duds\u0026start\u003d0\u0026hl\u003den\u0026q\u003dfuzzy+monkey",
"searchResultTime":"0.39"
}
},
"responseDetails":null,"responseStatus":200
}
JSON to XML
Fortunately, thanks to a free Java library called java-json, code is available to convert JSON into XML so that it can be used by DB2 for i and, by extension, any of the ILE languages—such as RPG, C, or COBOL—using embedded SQL. If you're not a Java developer, don't worry. All you have to do is compile the code once, and from there you never have to worry about Java again as it will stay "under the covers."
I have created an external user-defined function (UDF) called JSON2XML that will accept a string (CLOB data type) and return XML (as a CLOB). A sample invocation that wraps the prior example is shown here:
SELECT QGPL.JSON2XML(data) AS XMLData FROM (VALUES(SYSTOOLS.HTTPGETCLOB('https://ajax.googleapis.com/ajax/services/search/images?v=1.0&;q=fuzzy%20monkey',''))) WS(data);
The JSON data is retrieved from the image search API and then put through the JSON2XML function to convert it to XML. The transformed JSON now looks like the following in XML:
<responseData>
<cursor>
<moreResultsUrl>http://www.google.com/images?oe=utf8&;amp;ie=utf8&source=uds&start=0&hl=en&q=fuzzy+monkey</moreResultsUrl>
… more goes here …
</cursor>
<results>
<titleNoFormatting>fuzzy-monkey-1.jpg</titleNoFormatting>
<tbUrl>http://t1.gstatic.com/images?q=tbn:ANd9GcQQigy-U6KTXke82n5hma5qvFM2UyVnkGtJme6pkZgl_1GYM--Yb90oqnOJ</tbUrl>
<originalContextUrl>http://stackoverflow.com/questions/17773949/rails-best-way-to-extract-values-from-response-hash<;/originalContextUrl>
<width>1152</width>
<unescapedUrl>http://www.blirk.net/wallpapers/1152x864/fuzzy-monkey-1.jpg<;/unescapedUrl>
<url>http://www.blirk.net/wallpapers/1152x864/fuzzy-monkey-1.jpg<;/url>
<visibleUrl>stackoverflow.com</visibleUrl><b>fuzzy</b>-<b>monkey</b>-1.jpg
<GsearchResultClass>GimageSearch</GsearchResultClass>
<tbWidth>150</tbWidth>
<title><b>fuzzy</b>-<b>monkey</b>-1.jpg</title>
<height>864</height>
<imageId>ANd9GcQQigy-U6KTXke82n5hma5qvFM2UyVnkGtJme6pkZgl_1GYM--Yb90oqnOJ</imageId>
<contentNoFormatting>fuzzy-monkey-1.jpg</contentNoFormatting>
<tbHeight>113</tbHeight>
</results>
<results> … more results here … </results>
</responseData>
<responseDetails>null</responseDetails>
<responseStatus>200</responseStatus>
With this simple UDF, any JSON REST API can now also return XML! Thereafter, using the built-in XML functionality in IBM i 7.1, it becomes a snap to parse the XML:
WITH SEARCH_RESULTS AS (
SELECT '<root>'||QGPL.JSON2XML(data)||'</root>' AS XMLData FROM (VALUES(SYSTOOLS.HTTPGETCLOB('https://ajax.googleapis.com/ajax/services/search/images?v=1.0&;q=AS400',''))) WS(data)
)
SELECT WebServiceResult.*
FROM SEARCH_RESULTS,
XMLTABLE('$doc/root/responseData/results'
PASSING
XMLPARSE(DOCUMENT XMLData) AS "doc"
COLUMNS
titleNoFormatting VARCHAR(128) PATH 'titleNoFormatting',
ThumbNailUrl VARCHAR(1024) PATH 'tbUrl',
originalContextUrl VARCHAR(1024) PATH 'originalContextUrl',
width INT PATH 'width',
length INT PATH 'width',
height INT PATH 'height'
) AS WebServiceResult;
Notice that I added a root element (which the Java code does not do) so that XMLPARSE would accept the XML string as a valid document. Thereafter, XMLTABLE is used to break out the desired elements into a tabular format. The results of the above query are shown here:
Figure 1: These are the results of the Google REST API query.
If you're not on IBM i 7.1 yet, alternatively, the XML can be parsed using RPG.
There is much more to this Google image search API than shown here (such as whether or not there is more data to retrieve, etc.), but this query shows the basics of how to parse the main data. Given that many JSON-based REST API results will need to be analyzed multiple times for things like a response code, current data, whether or not more data is available with another call, etc., I suggest calling the API once and persisting the XML in a variable. With the response persisted, you don't have to go through the expense of invoking the API multiple times to analyze the various values.
XML to JSON
The java-json library also provides a way to create JSON data from XML. Therefore I decided to throw in a related UDF called XML2JSON to take advantage of this feature. This UDF accepts an XML string (as a CLOB) and returns a JSON string (as a CLOB).
The UDF can be invoked as follows:
SELECT QGPL.XML2JSON(CLOB('<mybigXMLstring />')) AS JSONData
FROM SYSIBM.SYSDUMMY1;
Incidentally, because of the improved UDF resolution, the CLOB cast is not required in IBM i 7.2.
This example assumes you already have an XML string ready to transform to JSON. You can also indirectly create JSON from a relational database query that uses the DB2 for i 7.1 XML composition features:
SELECT QGPL.XML2JSON(
XMLSERIALIZE(XMLAGG(XMLROW(
CUSNUM AS "CustomerId",
RTRIM(LSTNAM) AS "Name",
ZIPCOD AS "ZipCode",
BALDUE AS "BalDue"
OPTION ROW "Customer")) AS CLOB)) AS JSON
FROM QIWS.QCUSTCDT;
The resulting JSON (abridged and formatted) is shown here:
{"Customer":
[{"Name":"Henning","CustomerId":938472,"ZipCode":75217,"BalDue":37},
{"Name":"Jones","CustomerId":839283,"ZipCode":13041,"BalDue":100},
{"Name":"Vine","CustomerId":392859,"ZipCode":5046,"BalDue":439},
… more here …
{"Name":"Abraham","CustomerId":583990,"ZipCode":56342,"BalDue":500}
]}
Installing the Java UDFs
The Java code called JSON_UDFs.java is available for download. The user-defined functions should work on V5R4 and later, but use of the DB2 for i XMLTABLE table function requires IBM i 7.1 (and for best results, make sure the latest database group PTF package has been loaded).
The instructions for compiling the Java code are in the source code's header. Remember, as noted in the instructions, a standalone Java class intended for use by DB2 for i should be placed in this special folder: /qibm/userdata/os400/sqllib/function
In addition to the source code, you'll need to download the java-json.jar package from this link.
Once downloaded, unzip the jar file and put it in your jar folder on the IFS (for simplicity, I just used /tmp for my jar and Java source file). Unless you include the jar as part of your default class path, you'll need to make the jar available for use with DB2 using the install_jar procedure (overriding the jar path and schema as needed):
call sqlj.install_jar ('file:/tmp/java-json.jar','QGPL.java-json',0)
A commit statement is required after calling the install_jar procedure:
commit
Once the class and jar files are in place for DB2 to use, the remaining work is to define the external functions using the CREATE FUNCTION statement. This step tells DB2 how to get to the Java code:
CREATE OR REPLACE FUNCTION QGPL.JSON2XML(JSONData CLOB)
RETURNS CLOB
SPECIFIC QGPL.JSON2XML_CLOB
EXTERNAL NAME 'UDFs.convertJSON2XML'
LANGUAGE Java
PARAMETER STYLE Java
FENCED
NO SQL
RETURNS NULL ON NULL INPUT
SCRATCHPAD
DETERMINISTIC
CREATE OR REPLACE FUNCTION QGPL.XML2JSON(XMLData CLOB)
RETURNS CLOB
SPECIFIC QGPL.XML2JSON_CLOB
EXTERNAL NAME 'JSON_UDFs.convertXML2JSON'
LANGUAGE Java
PARAMETER STYLE Java
FENCED
NO SQL
RETURNS NULL ON NULL INPUT
SCRATCHPAD
DETERMINISTIC
The UDFs should now be available for use with DB2.
Caveats
- If you don't have the opportunity to optimize or manipulate the source JSON or XML, then the resulting XML or JSON data may be suboptimal.
- This utility is meant to be "easy." However, if performance is an issue or if strict control over the JSON output is required, I'd use a library like Scott Klement's YAJL for creating or parsing JSON.
- This UDF has the capacity to be quite a memory hog. If you're transforming large XML or JSON strings, use it carefully or use YAJL.
Conclusion
Working with JSON is fast becoming a way of life when retrieving data from external systems. While JSON isn't terribly difficult to construct, it can be a pain in the neck to consume without a helper library. DB2 for i developers can take advantage of the java-json library to convert between XML and JSON, thereby making the task of working with JSON data a little easier.
LATEST COMMENTS
MC Press Online