create or replace package body json_util_pkg as /* Purpose: JSON utilities for PL/SQL Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created */ g_json_null_object constant varchar2(20) := '{ }'; function get_xml_to_json_stylesheet return varchar2 as begin /* Purpose: return XSLT stylesheet for XML to JSON transformation Remarks: see http://code.google.com/p/xml2json-xslt/ Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created MBR 30.01.2010 Added fix for nulls */ return ' 0123456789 " " true false :null , } { : , } [ null , ] '; end get_xml_to_json_stylesheet; function ref_cursor_to_json (p_ref_cursor in sys_refcursor, p_max_rows in number := null, p_skip_rows in number := null) return clob as l_ctx dbms_xmlgen.ctxhandle; l_num_rows pls_integer; l_xml xmltype; l_json xmltype; l_returnvalue clob; begin /* Purpose: generate JSON from REF Cursor Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created */ l_ctx := dbms_xmlgen.newcontext (p_ref_cursor); dbms_xmlgen.setnullhandling (l_ctx, dbms_xmlgen.empty_tag); -- for pagination if p_max_rows is not null then dbms_xmlgen.setmaxrows (l_ctx, p_max_rows); end if; if p_skip_rows is not null then dbms_xmlgen.setskiprows (l_ctx, p_skip_rows); end if; -- get the XML content l_xml := dbms_xmlgen.getxmltype (l_ctx, dbms_xmlgen.none); l_num_rows := dbms_xmlgen.getnumrowsprocessed (l_ctx); dbms_xmlgen.closecontext (l_ctx); close p_ref_cursor; if l_num_rows > 0 then -- perform the XSL transformation l_json := l_xml.transform (xmltype(get_xml_to_json_stylesheet)); l_returnvalue := l_json.getclobval(); else l_returnvalue := g_json_null_object; end if; l_returnvalue := dbms_xmlgen.convert (l_returnvalue, dbms_xmlgen.entity_decode); return l_returnvalue; end ref_cursor_to_json; function sql_to_json (p_sql in varchar2, p_param_names in t_str_array := null, p_param_values in t_str_array := null, p_max_rows in number := null, p_skip_rows in number := null) return clob as l_ctx dbms_xmlgen.ctxhandle; l_num_rows pls_integer; l_xml xmltype; l_json xmltype; l_returnvalue clob; begin /* Purpose: generate JSON from SQL statement Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created MBR 28.07.2010 Handle null value in bind variable value (issue and solution reported by Matt Nolan) */ l_ctx := dbms_xmlgen.newcontext (p_sql); dbms_xmlgen.setnullhandling (l_ctx, dbms_xmlgen.empty_tag); -- bind variables, if any if p_param_names is not null then for i in 1..p_param_names.count loop dbms_xmlgen.setbindvalue (l_ctx, p_param_names(i), nvl(p_param_values(i), '')); end loop; end if; -- for pagination if p_max_rows is not null then dbms_xmlgen.setmaxrows (l_ctx, p_max_rows); end if; if p_skip_rows is not null then dbms_xmlgen.setskiprows (l_ctx, p_skip_rows); end if; -- get the XML content l_xml := dbms_xmlgen.getxmltype (l_ctx, dbms_xmlgen.none); l_num_rows := dbms_xmlgen.getnumrowsprocessed (l_ctx); dbms_xmlgen.closecontext (l_ctx); -- perform the XSL transformation if l_num_rows > 0 then l_json := l_xml.transform (xmltype(get_xml_to_json_stylesheet)); l_returnvalue := l_json.getclobval(); l_returnvalue := dbms_xmlgen.convert (l_returnvalue, dbms_xmlgen.entity_decode); else l_returnvalue := g_json_null_object; end if; return l_returnvalue; end sql_to_json; end json_util_pkg; /