# PLJSON_UTIL_PKG ## Package Specification ```sql package pljson_util_pkg authid current_user as /* Purpose: JSON utilities for PL/SQL see http://ora-00001.blogspot.com/ Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created JKR 01.05.2010 Edited to fit in PL/JSON JKR 19.01.2011 Newest stylesheet + bugfix handling */ -- generate JSON from REF Cursor function ref_cursor_to_json (p_ref_cursor in sys_refcursor, p_max_rows in number := null, p_skip_rows in number := null) return pljson_list; -- generate JSON from SQL statement function sql_to_json (p_sql in varchar2, p_max_rows in number := null, p_skip_rows in number := null) return pljson_list; end pljson_util_pkg;``` ## Package Body ```sql package body pljson_util_pkg as scanner_exception exception; pragma exception_init(scanner_exception, -20100); parser_exception exception; pragma exception_init(parser_exception, -20101); /* Purpose: JSON utilities for PL/SQL Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created */ function get_xml_to_json_stylesheet return varchar2 as stylesheet varchar2(32767); nls_numeric_characters varchar2(2); 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 */ stylesheet := q'^ 0123456789 " " true false { : null , } [ null , ] ^'; select value into nls_numeric_characters from nls_session_parameters where parameter = 'NLS_NUMERIC_CHARACTERS'; return replace(stylesheet, '{{nls_numeric_characters}}', nls_numeric_characters); 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 pljson_list as l_ctx dbms_xmlgen.ctxhandle; l_num_rows pls_integer; l_xml xmltype; l_xsl xmltype := xmltype(get_xml_to_json_stylesheet); l_returnvalue clob; begin /* Purpose: generate JSON from REF Cursor Remarks: Who Date Description ------ ---------- ------------------------------------- MBR 30.01.2010 Created JKR 01.05.2010 Edited to fit in PL/JSON */ 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 return pljson_list(); end if; --dbms_output.put_line(l_xml.getstringval); -- perform the XSL transformation SELECT l_xml.transform(l_xsl).getclobval() INTO l_returnvalue FROM DUAL; --dbms_output.put_line(l_returnvalue); if(l_num_rows > 1) then return pljson_list(pljson(l_returnvalue).get('ROWSET')); end if; declare ret pljson_list := pljson_list(); begin ret.append( pljson( pljson(l_returnvalue).get('ROWSET') ).get('ROW') ); return ret; end; exception when scanner_exception then dbms_output.put('Scanner problem with the following input: '); dbms_output.put_line(l_returnvalue); raise; when parser_exception then dbms_output.put('Parser problem with the following input: '); dbms_output.put_line(l_returnvalue); raise; when others then raise; end ref_cursor_to_json; function sql_to_json (p_sql in varchar2, p_max_rows in number := null, p_skip_rows in number := null) return pljson_list as v_cur sys_refcursor; begin open v_cur for p_sql; return ref_cursor_to_json(v_cur, p_max_rows, p_skip_rows); end sql_to_json; end pljson_util_pkg;```