├── .gitignore ├── AUTHORS.md ├── CHANGELOG.md ├── LICENSE-MIT ├── README.md ├── install.sql ├── json_debug.pkb ├── json_debug.pks ├── json_parser.pkb ├── json_parser.pks ├── json_sql.pkb ├── json_sql.pks ├── json_utils.pkb ├── json_utils.pks ├── jsonarray.tpb ├── jsonarray.tps ├── jsonkeys.tps ├── jsonnode.tpb ├── jsonnode.tps ├── jsonnodes.tps ├── jsonobject.tpb ├── jsonobject.tps ├── jsonvalue.tpb ├── jsonvalue.tps ├── uninstall.sql ├── unittest ├── UT_util.pkb ├── UT_util.pks ├── json_sql_ut.pkb ├── json_sql_ut.pks ├── json_ut.pkb ├── json_ut.pks └── unittest.sql └── user.sql /.gitignore: -------------------------------------------------------------------------------- 1 | *.log 2 | -------------------------------------------------------------------------------- /AUTHORS.md: -------------------------------------------------------------------------------- 1 | Dieter Oberkofler 2 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Changelog 2 | 3 | All notable changes to this project will be documented in this file. 4 | 5 | The format is based on [Keep a Changelog](http://keepachangelog.com/en/1.0.0/) 6 | and this project adheres to [Semantic Versioning](http://semver.org/spec/v2.0.0.html). 7 | 8 | 9 | ## [?.?.?] - ????-??-?? 10 | 11 | ### Added 12 | ### Changed 13 | ### Fixed 14 | 15 | 16 | ## [0.7.1] - 2020-03-11 17 | 18 | ### Fixed 19 | - Fixed an alignment problem in the pretty output of json. 20 | 21 | 22 | ## [0.7.0] - 2020-03-09 23 | 24 | ### Changed 25 | - Added output configuration option `newline_char` for the end of line style and `indentation_char` for the indentation style. 26 | 27 | 28 | ## [0.6.0] - 2020-03-09 29 | 30 | ### Changed 31 | - Added api `get_default_options`, `get_options` and `set_options` to `json_utils`package to configure (`Pretty`, `ascii_output` and `escape_solitus`) the output. 32 | - Added support for formatted (pretty) json output with the option `Pretty`. 33 | 34 | 35 | ### Fixed 36 | - Fixed another error when converting `\f` and `\r`. 37 | 38 | 39 | ## [0.5.0] - 2020-03-08 40 | 41 | ### Changed 42 | - No longer install debug module by default. 43 | - Removed package `json_cost` and `json_clob`. 44 | - Removed the obsolete performance tests. 45 | 46 | 47 | ### Fixed 48 | - Required naming changes to run on current Oracle versions that now also have json support. 49 | - Fixed an error when converting `\f` and `\r`. 50 | 51 | 52 | ## [0.4.1] - 2016-12-22 53 | 54 | ### Changed 55 | - Improved the performance when working with CLOB values by 10 to 100 times depending on the actual CLOB length. (Dieter Oberkofler) 56 | 57 | 58 | ## [0.4.0] - 2016-12-8 59 | 60 | ### Added 61 | - Added support for CLOB properties. (Dieter Oberkofler) 62 | - Added support to update properties. (Dieter Oberkofler) 63 | - Added a new module json_sql that allows to dynamically generate a json representation of the rows in a select with bind variables. (Dieter Oberkofler) 64 | 65 | 66 | ## [0.3.1] - 2016-03-16 67 | 68 | ### Fixed 69 | - Fixed a problem when escaping a string that ends with CHR(10). (Dieter Oberkofler) 70 | 71 | 72 | ## [0.3.0] - 2014-12-15 73 | 74 | ### Added 75 | - Improved the performance of object_to_clob and array_to_clob by up to 400%. (Dieter Oberkofler) 76 | - Added a few special values tests. (Dieter Oberkofler) 77 | 78 | 79 | ## [0.2.0] - 2014-06-19 80 | 81 | ### Added 82 | - Now using 3 individual parse methods in json_parser allowing to parse an object, an array or any of the two. (Dieter Oberkofler) 83 | - Added a new constructor to json_array allowing to parse a JSON string representing an array. Proposed by matthias-oe. (Dieter Oberkofler) 84 | - Added a new constructor to json_value allowing to parse a JSON string representing an object or an array. (Dieter Oberkofler) 85 | - Added unit tests for the new functionality. (Dieter Oberkofler) 86 | 87 | 88 | ## [0.1.0] - 2014-04-26 89 | 90 | ### Added 91 | - Added support for DATE types. 92 | - Added support for JSONP. 93 | 94 | 95 | ## [0.0.1] - 2013-09-24 96 | 97 | ### Added 98 | - Initial release of plsql_json. 99 | -------------------------------------------------------------------------------- /LICENSE-MIT: -------------------------------------------------------------------------------- 1 | Copyright (c) 2013 Dieter Oberkofler 2 | 3 | Permission is hereby granted, free of charge, to any person 4 | obtaining a copy of this software and associated documentation 5 | files (the "Software"), to deal in the Software without 6 | restriction, including without limitation the rights to use, 7 | copy, modify, merge, publish, distribute, sublicense, and/or sell 8 | copies of the Software, and to permit persons to whom the 9 | Software is furnished to do so, subject to the following 10 | conditions: 11 | 12 | The above copyright notice and this permission notice shall be 13 | included in all copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 16 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES 17 | OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND 18 | NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT 19 | HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, 20 | WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING 21 | FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR 22 | OTHER DEALINGS IN THE SOFTWARE. 23 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PLSQL-JSON: The JSON encode/decode library for PL/SQL 2 | PL/SQL-JSON implements encoding and decoding JSON in a PL/SQL environment. 3 | Using the objects json_object and json_array allows to compose and parse JSON. 4 | 5 | 6 | ### Install 7 | Install using the install.sql script and uninstall using uninstall.sql script. 8 | 9 | 10 | ### Unit test 11 | Unit tests are provided in the unitest directory and can be run using the unitest.sql script. 12 | 13 | 14 | ### Performance 15 | A performance test is avilable in the performance directory and allows to compare with the the excellent PL/JSON implementation. 16 | PLSQL-JSON is typically between two and then times faster. 17 | 18 | 19 | ### Documentation 20 | This README is currently the only avilable documentation. 21 | 22 | 23 | ### Release History 24 | See the [CHANGELOG](CHANGELOG). 25 | -------------------------------------------------------------------------------- /install.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * 3 | * NAME 4 | * install.sql 5 | * 6 | * AUTHOR 7 | * Dieter Oberkofler 8 | * 9 | * FUNCTION 10 | * Install the plsql_json objects 11 | * 12 | */ 13 | 14 | spool install.log 15 | 16 | set define off echo on termout off 17 | 18 | -- uninstall all object 19 | @@uninstall.sql 20 | 21 | 22 | -- install the headers 23 | @@json_clob.pks 24 | show errors 25 | @@jsonkeys.tps 26 | show errors 27 | @@jsonnode.tps 28 | show errors 29 | @@jsonnodes.tps 30 | show errors 31 | @@jsonvalue.tps 32 | show errors 33 | @@jsonobject.tps 34 | show errors 35 | @@jsonarray.tps 36 | show errors 37 | @@json_utils.pks 38 | show errors 39 | @@json_parser.pks 40 | show errors 41 | @@json_sql.pks 42 | show errors 43 | 44 | -- install the bodies 45 | @@json_clob.pkb 46 | show errors 47 | @@jsonnode.tpb 48 | show errors 49 | @@jsonvalue.tpb 50 | show errors 51 | @@jsonobject.tpb 52 | show errors 53 | @@jsonarray.tpb 54 | show errors 55 | @@json_utils.pkb 56 | show errors 57 | @@json_parser.pkb 58 | show errors 59 | @@json_sql.pkb 60 | show errors 61 | 62 | spool off 63 | 64 | set define on echo off termout on 65 | -------------------------------------------------------------------------------- /json_debug.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY json_debug 3 | IS 4 | 5 | PROCEDURE dumpRaw(theNodes IN jsonNodes, theResult IN OUT NOCOPY debugTableType); 6 | PROCEDURE dump(theNodes IN jsonNodes, theFirstNodeID IN NUMBER, theLevel IN OUT NUMBER, theResult IN OUT NOCOPY debugTableType); 7 | FUNCTION dump(theNodes IN jsonNodes, theNodeID IN NUMBER, theLevel IN NUMBER) RETURN debugRecordType; 8 | FUNCTION lalign(theString IN VARCHAR2, theSize IN BINARY_INTEGER) RETURN VARCHAR2; 9 | FUNCTION ralign(theString IN VARCHAR2, theSize IN BINARY_INTEGER) RETURN VARCHAR2; 10 | 11 | ---------------------------------------------------------- 12 | -- output 13 | -- 14 | FUNCTION dump(theNode IN jsonNode, theNodeID IN NUMBER DEFAULT NULL) RETURN VARCHAR2 15 | IS 16 | BEGIN 17 | RETURN CASE theNodeID IS NOT NULL WHEN TRUE THEN 'nodeID=('||theNodeID||') ' ELSE '' END || 18 | 'typ=('||theNode.typ||') nam=('||theNode.nam||') par=('||theNode.par||') nex=('||theNode.nex||') sub=('||theNode.sub||') str=('||theNode.str||') num=('||theNode.num||')'; 19 | END dump; 20 | 21 | ---------------------------------------------------------- 22 | -- output 23 | -- 24 | PROCEDURE output(theData IN jsonValue, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL) 25 | IS 26 | aTitle VARCHAR2(32767) := theTitle; 27 | BEGIN 28 | IF (aTitle IS NOT NULL) THEN 29 | aTitle := aTitle || ' - '; 30 | END IF; 31 | aTitle := aTitle || 'json_data('||theData.typ||')'; 32 | 33 | output(theNodes=>theData.nodes, theRawFlag=>theRawFlag, theTitle=>aTitle); 34 | END output; 35 | 36 | ---------------------------------------------------------- 37 | -- output 38 | -- 39 | PROCEDURE output(theObject IN jsonObject, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL) 40 | IS 41 | aTitle VARCHAR2(32767) := theTitle; 42 | BEGIN 43 | IF (aTitle IS NOT NULL) THEN 44 | aTitle := aTitle || ' - '; 45 | END IF; 46 | aTitle := aTitle || 'jsonObject with '||theObject.nodes.COUNT||' nodes and lastID is '||theObject.lastID; 47 | 48 | output(theNodes=>theObject.nodes, theRawFlag=>theRawFlag, theTitle=>aTitle); 49 | END output; 50 | 51 | ---------------------------------------------------------- 52 | -- output 53 | -- 54 | PROCEDURE output(theArray IN jsonArray, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL) 55 | IS 56 | aTitle VARCHAR2(32767) := theTitle; 57 | BEGIN 58 | IF (aTitle IS NOT NULL) THEN 59 | aTitle := aTitle || ' - '; 60 | END IF; 61 | aTitle := aTitle || 'jsonArray with '||theArray.nodes.COUNT||' nodes and lastID is '||theArray.lastID; 62 | 63 | output(theNodes=>theArray.nodes, theRawFlag=>theRawFlag, theTitle=>aTitle); 64 | END output; 65 | 66 | ---------------------------------------------------------- 67 | -- output 68 | -- 69 | PROCEDURE output(theNodes IN jsonNodes, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL) 70 | IS 71 | r debugTableType := debugTableType(); 72 | i BINARY_INTEGER; 73 | l BINARY_INTEGER; 74 | n BINARY_INTEGER := 1; 75 | 76 | PROCEDURE output_line(theLevel IN VARCHAR2, theNo IN VARCHAR2, theNodeID IN VARCHAR2, theType IN VARCHAR2, theName IN VARCHAR2, theArrayIndex IN VARCHAR2, theParentID IN VARCHAR2, theNextID IN VARCHAR2, theSubNodeID IN VARCHAR2, theValue IN VARCHAR2) 77 | IS 78 | BEGIN 79 | dbms_output.put_line( lalign(theLevel, 10) || ' ' || 80 | ralign(theNo, 5) || ' ' || 81 | ralign(theNodeID, 10) || ' ' || 82 | lalign(theType, 15) || ' ' || 83 | lalign(NVL(theName, '-'), 30) || ' ' || 84 | ralign(NVL(theArrayIndex, '-'), 5) || ' ' || 85 | ralign(NVL(theParentID, '-'), 10) || ' ' || 86 | ralign(NVL(theNextID, '-'), 10) || ' ' || 87 | ralign(NVL(theSubNodeID, '-'), 10) || ' ' || 88 | lalign(theValue, 60) 89 | ); 90 | END output_line; 91 | BEGIN 92 | IF (theTitle IS NOT NULL) THEN 93 | dbms_output.put_line('.'); 94 | dbms_output.put_line('---------- '||theTitle||' - BEGIN ----------'); 95 | END IF; 96 | 97 | IF (theRawFlag) THEN 98 | dumpRaw(theNodes=>theNodes, theResult=>r); 99 | ELSE 100 | dump(theNodes=>theNodes, theFirstNodeID=>theNodes.FIRST, theLevel=>l, theResult=>r); 101 | END IF; 102 | 103 | output_line('Level', '#', 'Node#', 'Type', 'Name', 'Index', 'Parent', 'Next', 'Sub', 'Value'); 104 | output_line('----------', '-----', '----------', '---------------', '------------------------------', '-----', '----------', '----------', '----------', '------------------------------------------------------------'); 105 | 106 | i := r.FIRST; 107 | WHILE (i IS NOT NULL) LOOP 108 | output_line( theLevel => RPAD('*', NVL(r(i).nodeLevel, 0) + 1, '*'), 109 | theNo => n, 110 | theNodeID => r(i).nodeID, 111 | theType => r(i).nodeTypeName||'('||r(i).nodeType||')', 112 | theArrayIndex => r(i).arrayIndex, 113 | theValue => r(i).nodeValue, 114 | theParentID => r(i).parentID, 115 | theNextID => r(i).nextID, 116 | theSubNodeID => r(i).subNodeID, 117 | theName => r(i).nodeName 118 | ); 119 | n := n + 1; 120 | i := r.NEXT(i); 121 | END LOOP; 122 | 123 | IF (theTitle IS NOT NULL) THEN 124 | dbms_output.put_line('---------- '||theTitle||' - END ------------'); 125 | dbms_output.put_line('.'); 126 | END IF; 127 | END output; 128 | 129 | ---------------------------------------------------------- 130 | -- asTable 131 | -- 132 | FUNCTION asTable(theNodes IN jsonNodes, theRawFlag IN BOOLEAN DEFAULT FALSE) RETURN debugTableType PIPELINED 133 | IS 134 | r debugTableType := debugTableType(); 135 | i BINARY_INTEGER; 136 | l BINARY_INTEGER; 137 | BEGIN 138 | IF (theRawFlag) THEN 139 | dumpRaw(theNodes=>theNodes, theResult=>r); 140 | ELSE 141 | dump(theNodes=>theNodes, theFirstNodeID=>theNodes.FIRST, theLevel=>l, theResult=>r); 142 | END IF; 143 | 144 | i := r.FIRST; 145 | WHILE (i IS NOT NULL) LOOP 146 | PIPE ROW(r(i)); 147 | i := r.NEXT(i); 148 | END LOOP; 149 | 150 | RETURN; 151 | END asTable; 152 | 153 | ---------------------------------------------------------- 154 | -- dumpRaw (private) 155 | -- 156 | PROCEDURE dumpRaw(theNodes IN jsonNodes, theResult IN OUT NOCOPY debugTableType) 157 | IS 158 | i BINARY_INTEGER; 159 | BEGIN 160 | i := theNodes.FIRST; 161 | WHILE (i IS NOT NULL) LOOP 162 | theResult.EXTEND(1); 163 | theResult(theResult.LAST) := dump(theNodes=>theNodes, theNodeID=>i, theLevel=>NULL); 164 | i := theNodes.NEXT(i); 165 | END LOOP; 166 | END dumpRaw; 167 | 168 | ---------------------------------------------------------- 169 | -- dump (private) 170 | -- 171 | PROCEDURE dump(theNodes IN jsonNodes, theFirstNodeID IN NUMBER, theLevel IN OUT NUMBER, theResult IN OUT NOCOPY debugTableType) 172 | IS 173 | l BINARY_INTEGER := NVL(theLevel, 0); 174 | i BINARY_INTEGER := theFirstNodeID; 175 | BEGIN 176 | WHILE (i IS NOT NULL) LOOP 177 | IF (theNodes(i).typ IN ('O', 'A')) THEN 178 | theResult.EXTEND(1); 179 | theResult(theResult.LAST) := dump(theNodes=>theNodes, theNodeID=>i, theLevel=>l); 180 | 181 | l := l + 1; 182 | dump(theNodes=>theNodes, theFirstNodeID=>theNodes(i).sub, theLevel=>l, theResult=>theResult); 183 | l := l - 1; 184 | ELSE 185 | theResult.EXTEND(1); 186 | theResult(theResult.LAST) := dump(theNodes=>theNodes, theNodeID=>i, theLevel=>l); 187 | END IF; 188 | 189 | i := theNodes(i).nex; 190 | END LOOP; 191 | END dump; 192 | 193 | ---------------------------------------------------------- 194 | -- dump (private) 195 | -- 196 | FUNCTION dump(theNodes IN jsonNodes, theNodeID IN NUMBER, theLevel IN NUMBER) RETURN debugRecordType 197 | IS 198 | n CONSTANT jsonNode := theNodes(theNodeID); 199 | r debugRecordType; 200 | 201 | FUNCTION getArrayIndex(theNodes IN jsonNodes, theNodeID IN NUMBER) RETURN NUMBER 202 | IS 203 | p BINARY_INTEGER; 204 | i BINARY_INTEGER; 205 | x BINARY_INTEGER; 206 | BEGIN 207 | r.arrayIndex := NULL; 208 | p := theNodes(theNodeID).par; 209 | IF (p IS NOT NULL AND theNodes(p).typ = 'A') THEN 210 | --dbms_output.put_line('node '||theNodeID||' is part of an an array'); 211 | x := 0; 212 | i := theNodes(p).sub; 213 | WHILE (i IS NOT NULL) LOOP 214 | IF (i = theNodeID) THEN 215 | RETURN x; 216 | END IF; 217 | x := x + 1; 218 | i := theNodes(i).nex; 219 | END LOOP; 220 | END IF; 221 | 222 | RETURN NULL; 223 | END getArrayIndex; 224 | BEGIN 225 | -- type independent information 226 | r.nodeLevel := theLevel; 227 | r.nodeType := n.typ; 228 | r.nodeID := theNodeID; 229 | r.nodeName := n.nam; 230 | r.parentID := n.par; 231 | r.nextID := n.nex; 232 | r.subNodeID := n.sub; 233 | 234 | -- compute the array index 235 | r.arrayIndex := getArrayIndex(theNodes=>theNodes, theNodeID=>theNodeID); 236 | 237 | -- type dependent information 238 | CASE n.typ 239 | 240 | WHEN json_utils.NODE_TYPE_NULL THEN 241 | r.nodeTypeName := 'NULL'; 242 | r.nodeValue := NULL; 243 | 244 | WHEN json_utils.NODE_TYPE_STRING THEN 245 | r.nodeTypeName := 'STRING'; 246 | IF (n.str IS NOT NULL) THEN 247 | r.nodeValue := SUBSTR(n.str, 1, 2000); 248 | END IF; 249 | 250 | WHEN json_utils.NODE_TYPE_LOB THEN 251 | r.nodeTypeName := 'LOB'; 252 | IF (dbms_lob.getlength(lob_loc=>n.lob) > 0) THEN 253 | r.nodeValue := dbms_lob.substr(lob_loc=>n.lob, amount=>2000, offset=>1); 254 | END IF; 255 | 256 | WHEN json_utils.NODE_TYPE_NUMBER THEN 257 | r.nodeTypeName := 'NUMBER'; 258 | IF (n.num IS NOT NULL) THEN 259 | r.nodeValue := TO_CHAR(n.num); 260 | END IF; 261 | 262 | WHEN json_utils.NODE_TYPE_DATE THEN 263 | r.nodeTypeName := 'DATE'; 264 | IF (n.dat IS NOT NULL) THEN 265 | r.nodeValue := TO_CHAR(n.dat, 'YYYYMMDD HH24MISS'); 266 | END IF; 267 | 268 | WHEN json_utils.NODE_TYPE_BOOLEAN THEN 269 | r.nodeTypeName := 'BOOL'; 270 | IF (n.num IS NOT NULL) THEN 271 | r.nodeValue := CASE n.num WHEN 1 THEN 'true' ELSE 'false' END; 272 | END IF; 273 | 274 | WHEN json_utils.NODE_TYPE_OBJECT THEN 275 | r.nodeTypeName := '[OBJECT]'; 276 | 277 | WHEN json_utils.NODE_TYPE_ARRAY THEN 278 | r.nodeTypeName := '[ARRAY]'; 279 | 280 | ELSE 281 | r.nodeType := TO_CHAR(n.typ); 282 | 283 | END CASE; 284 | 285 | RETURN r; 286 | END dump; 287 | 288 | ---------------------------------------------------------- 289 | -- lalign (private) 290 | -- 291 | FUNCTION lalign(theString IN VARCHAR2, theSize IN BINARY_INTEGER) RETURN VARCHAR2 292 | IS 293 | l BINARY_INTEGER := LENGTH(theString); 294 | BEGIN 295 | IF (theString IS NULL OR l IS NULL OR l = 0) THEN 296 | RETURN RPAD(' ', theSize, ' '); 297 | ELSIF (l = theSize) THEN 298 | RETURN theString; 299 | ELSIF (l > theSize) THEN 300 | RETURN SUBSTR(theString, 1, theSize); 301 | ELSE 302 | RETURN RPAD(theString, theSize, ' '); 303 | END IF; 304 | END lalign; 305 | 306 | ---------------------------------------------------------- 307 | -- ralign (private) 308 | -- 309 | FUNCTION ralign(theString IN VARCHAR2, theSize IN BINARY_INTEGER) RETURN VARCHAR2 310 | IS 311 | l BINARY_INTEGER := LENGTH(theString); 312 | BEGIN 313 | IF (theString IS NULL OR l IS NULL OR l = 0) THEN 314 | RETURN RPAD(' ', theSize, ' '); 315 | ELSIF (l = theSize) THEN 316 | RETURN theString; 317 | ELSIF (l > theSize) THEN 318 | RETURN SUBSTR(theString, 1, theSize); 319 | ELSE 320 | RETURN LPAD(theString, theSize, ' '); 321 | END IF; 322 | END ralign; 323 | 324 | END json_debug; 325 | / 326 | -------------------------------------------------------------------------------- /json_debug.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_debug 3 | IS 4 | 5 | TYPE debugRecordType IS RECORD 6 | ( 7 | nodeLevel NUMBER, 8 | nodeType VARCHAR2(30), 9 | nodeTypeName VARCHAR2(30), 10 | nodeName VARCHAR2(2000), 11 | arrayIndex NUMBER, 12 | nodeValue VARCHAR2(2000), 13 | nodeID NUMBER, 14 | parentID NUMBER, 15 | nextID NUMBER, 16 | subNodeID NUMBER 17 | ); 18 | TYPE debugTableType IS TABLE OF debugRecordType; 19 | 20 | FUNCTION dump(theNode IN jsonNode, theNodeID IN NUMBER DEFAULT NULL) RETURN VARCHAR2; 21 | PROCEDURE output(theData IN jsonValue, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL); 22 | PROCEDURE output(theObject IN jsonObject, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL); 23 | PROCEDURE output(theArray IN jsonArray, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL); 24 | PROCEDURE output(theNodes IN jsonNodes, theRawFlag IN BOOLEAN DEFAULT FALSE, theTitle IN VARCHAR2 DEFAULT NULL); 25 | FUNCTION asTable(theNodes IN jsonNodes, theRawFlag IN BOOLEAN DEFAULT FALSE) RETURN debugTableType PIPELINED; 26 | 27 | END json_debug; 28 | / 29 | -------------------------------------------------------------------------------- /json_parser.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY json_parser IS 3 | 4 | ---------------------------------------------------------- 5 | -- PRIVATE EXCEPTIONS 6 | ---------------------------------------------------------- 7 | 8 | ---------------------------------------------------------- 9 | -- PRIVATE TYPES 10 | ---------------------------------------------------------- 11 | 12 | ---------------------------------------------------------- 13 | -- PRIVATE CONSTANTS 14 | ---------------------------------------------------------- 15 | 16 | ---------------------------------------------------------- 17 | -- PRIVATE VARIABLES 18 | ---------------------------------------------------------- 19 | 20 | decimalpoint VARCHAR2(1 CHAR) := '.'; 21 | 22 | ---------------------------------------------------------- 23 | -- LOCAL MODULES 24 | ---------------------------------------------------------- 25 | 26 | FUNCTION next_char(indx NUMBER, s IN OUT NOCOPY json_src) RETURN VARCHAR2; 27 | FUNCTION next_char2(indx NUMBER, s IN OUT NOCOPY json_src, amount NUMBER DEFAULT 1) RETURN VARCHAR2; 28 | 29 | FUNCTION prepareClob(buf IN CLOB) RETURN json_src; 30 | FUNCTION prepareVARCHAR2(buf IN VARCHAR2) RETURN json_src; 31 | FUNCTION lexer(jsrc IN OUT NOCOPY json_src) RETURN lTokens; 32 | 33 | PROCEDURE parseMem(tokens lTokens, indx IN OUT PLS_INTEGER, mem_name VARCHAR2, mem_indx NUMBER, theParentID IN OUT BINARY_INTEGER, theLastID IN OUT BINARY_INTEGER, theNodes IN OUT NOCOPY jsonNodes); 34 | 35 | ---------------------------------------------------------- 36 | -- GLOBAL MODULES 37 | ---------------------------------------------------------- 38 | 39 | ---------------------------------------------------------- 40 | -- updateDecimalPoint (private) 41 | -- 42 | PROCEDURE updateDecimalPoint 43 | IS 44 | BEGIN 45 | SELECT SUBSTR(VALUE, 1, 1) INTO decimalpoint FROM nls_session_parameters WHERE parameter = 'NLS_NUMERIC_CHARACTERS'; 46 | END updateDecimalPoint; 47 | 48 | ---------------------------------------------------------- 49 | -- next_char (private) 50 | -- type json_src is record (len number, offset number, src varchar2(10), s_clob clob); 51 | -- 52 | FUNCTION next_char(indx NUMBER, s IN OUT NOCOPY json_src) RETURN VARCHAR2 53 | IS 54 | BEGIN 55 | IF (indx > s.len) THEN 56 | RETURN NULL; 57 | END IF; 58 | 59 | -- right offset? 60 | IF (indx > 4000 + s.offset OR indx < s.offset) THEN 61 | -- load right offset 62 | s.offset := indx - (indx MOD 4000); 63 | s.src := dbms_lob.substr(s.s_clob, 4000, s.offset + 1); 64 | END IF; 65 | 66 | -- read from s.src 67 | RETURN substr(s.src, indx - s.offset, 1); 68 | END next_char; 69 | 70 | ---------------------------------------------------------- 71 | -- next_char2 (private) 72 | -- 73 | FUNCTION next_char2(indx NUMBER, s IN OUT NOCOPY json_src, amount NUMBER DEFAULT 1) RETURN VARCHAR2 74 | IS 75 | buf VARCHAR2(32767) := ''; 76 | BEGIN 77 | FOR I IN 1 .. amount LOOP 78 | buf := buf || next_char(indx-1+i,s); 79 | END LOOP; 80 | RETURN buf; 81 | END next_char2; 82 | 83 | ---------------------------------------------------------- 84 | -- prepareClob (private) 85 | -- 86 | function prepareClob(buf CLOB) RETURN json_src 87 | IS 88 | temp json_src; 89 | BEGIN 90 | temp.s_clob := buf; 91 | temp.offset := 0; 92 | temp.src := dbms_lob.substr(buf, 4000, temp.offset + 1); 93 | temp.len := dbms_lob.getlength(buf); 94 | RETURN temp; 95 | END prepareClob; 96 | 97 | ---------------------------------------------------------- 98 | -- prepareVarchar2 (private) 99 | -- 100 | FUNCTION prepareVarchar2(buf VARCHAR2) RETURN json_src 101 | IS 102 | temp json_src; 103 | begin 104 | temp.s_clob := buf; 105 | temp.offset := 0; 106 | temp.src := substr(buf, 1, 4000); 107 | temp.len := length(buf); 108 | RETURN temp; 109 | END prepareVarchar2; 110 | 111 | ---------------------------------------------------------- 112 | -- debug (private) 113 | -- 114 | PROCEDURE debug(text VARCHAR2) 115 | IS 116 | BEGIN 117 | --dbms_output.put_line(text); 118 | NULL; 119 | END debug; 120 | 121 | 122 | -- 123 | -- START SCANNER 124 | -- ************* 125 | 126 | 127 | ---------------------------------------------------------- 128 | -- s_error (private) 129 | -- 130 | PROCEDURE s_error(text VARCHAR2, line NUMBER, col NUMBER) 131 | IS 132 | BEGIN 133 | raise_application_error(-20100, 'JSON Scanner exception @ line: '||line||' column: '||col||' - '||text); 134 | END s_error; 135 | 136 | ---------------------------------------------------------- 137 | -- s_error (private) 138 | -- 139 | PROCEDURE s_error(text VARCHAR2, tok rToken) 140 | IS 141 | BEGIN 142 | raise_application_error(-20100, 'JSON Scanner exception @ line: '||tok.line||' column: '||tok.col||' - '||text); 143 | END s_error; 144 | 145 | ---------------------------------------------------------- 146 | -- mt (private) 147 | -- 148 | FUNCTION mt(t VARCHAR2, l PLS_INTEGER, c PLS_INTEGER, d VARCHAR2) RETURN rToken 149 | IS 150 | token rToken; 151 | BEGIN 152 | token.type_name := t; 153 | token.line := l; 154 | token.col := c; 155 | token.data := d; 156 | RETURN token; 157 | END mt; 158 | 159 | ---------------------------------------------------------- 160 | -- lexNumber (private) 161 | -- 162 | FUNCTION lexNumber(jsrc IN OUT NOCOPY json_src, tok IN OUT NOCOPY rToken, indx IN OUT NOCOPY PLS_INTEGER) RETURN PLS_INTEGER 163 | IS 164 | numbuf varchar2(4000) := ''; 165 | buf varchar2(4); 166 | checkLoop boolean; 167 | BEGIN 168 | buf := next_char(indx, jsrc); 169 | if(buf = '-') then numbuf := '-'; indx := indx + 1; end if; 170 | buf := next_char(indx, jsrc); 171 | --0 or [1-9]([0-9])* 172 | if(buf = '0') then 173 | numbuf := numbuf || '0'; indx := indx + 1; 174 | buf := next_char(indx, jsrc); 175 | elsif(buf >= '1' and buf <= '9') then 176 | numbuf := numbuf || buf; indx := indx + 1; 177 | --read digits 178 | buf := next_char(indx, jsrc); 179 | while(buf >= '0' and buf <= '9') loop 180 | numbuf := numbuf || buf; indx := indx + 1; 181 | buf := next_char(indx, jsrc); 182 | end loop; 183 | end if; 184 | --fraction 185 | if(buf = '.') then 186 | numbuf := numbuf || buf; indx := indx + 1; 187 | buf := next_char(indx, jsrc); 188 | checkLoop := FALSE; 189 | while(buf >= '0' and buf <= '9') loop 190 | checkLoop := TRUE; 191 | numbuf := numbuf || buf; indx := indx + 1; 192 | buf := next_char(indx, jsrc); 193 | end loop; 194 | if(not checkLoop) then 195 | s_error('Expected: digits in fraction', tok); 196 | end if; 197 | end if; 198 | --exp part 199 | if(buf in ('e', 'E')) then 200 | numbuf := numbuf || buf; indx := indx + 1; 201 | buf := next_char(indx, jsrc); 202 | if(buf = '+' or buf = '-') then 203 | numbuf := numbuf || buf; indx := indx + 1; 204 | buf := next_char(indx, jsrc); 205 | end if; 206 | checkLoop := FALSE; 207 | while(buf >= '0' and buf <= '9') loop 208 | checkLoop := TRUE; 209 | numbuf := numbuf || buf; indx := indx + 1; 210 | buf := next_char(indx, jsrc); 211 | end loop; 212 | if(not checkLoop) then 213 | s_error('Expected: digits in exp', tok); 214 | end if; 215 | end if; 216 | 217 | tok.data := numbuf; 218 | return indx; 219 | END lexNumber; 220 | 221 | ---------------------------------------------------------- 222 | -- lexName (private) 223 | -- 224 | -- [a-zA-Z]([a-zA-Z0-9])* 225 | -- 226 | FUNCTION lexName(jsrc IN OUT NOCOPY json_src, tok IN OUT NOCOPY rToken, indx IN OUT NOCOPY PLS_INTEGER) RETURN PLS_INTEGER 227 | IS 228 | varbuf varchar2(32767) := ''; 229 | buf varchar(4); 230 | num number; 231 | BEGIN 232 | buf := next_char(indx, jsrc); 233 | while(REGEXP_LIKE(buf, '^[[:alnum:]\_]$', 'i')) loop 234 | varbuf := varbuf || buf; 235 | indx := indx + 1; 236 | buf := next_char(indx, jsrc); 237 | if (buf is null) then 238 | goto retname; 239 | --debug('Premature string ending'); 240 | end if; 241 | end loop; 242 | <> 243 | 244 | --could check for reserved keywords here 245 | 246 | --debug(varbuf); 247 | tok.data := varbuf; 248 | return indx-1; 249 | END lexName; 250 | 251 | ---------------------------------------------------------- 252 | -- updateClob (private) 253 | -- 254 | PROCEDURE updateClob(v_extended IN OUT NOCOPY CLOB, v_str VARCHAR2) 255 | IS 256 | BEGIN 257 | dbms_lob.writeappend(v_extended, LENGTH(v_str), v_str); 258 | END updateClob; 259 | 260 | ---------------------------------------------------------- 261 | -- lexString (private) 262 | -- 263 | FUNCTION lexString(jsrc IN OUT NOCOPY json_src, tok IN OUT NOCOPY rToken, indx IN OUT NOCOPY PLS_INTEGER, endChar CHAR) RETURN PLS_INTEGER 264 | IS 265 | v_extended clob := null; v_count number := 0; 266 | varbuf varchar2(32767) := ''; 267 | buf varchar(4); 268 | wrong boolean; 269 | begin 270 | indx := indx +1; 271 | buf := next_char(indx, jsrc); 272 | while(buf != endChar) loop 273 | --clob control 274 | if(v_count > 8191) then --crazy oracle error (16383 is the highest working length with unistr - 8192 choosen to be safe) 275 | if(v_extended is null) then 276 | v_extended := empty_clob(); 277 | dbms_lob.createtemporary(v_extended, true); 278 | end if; 279 | updateClob(v_extended, unistr(varbuf)); 280 | varbuf := ''; v_count := 0; 281 | end if; 282 | if(buf = Chr(13) or buf = CHR(9) or buf = CHR(10)) then 283 | s_error('Control characters not allowed (CHR(9),CHR(10)CHR(13))', tok); 284 | end if; 285 | if(buf = '\') then 286 | --varbuf := varbuf || buf; 287 | indx := indx + 1; 288 | buf := next_char(indx, jsrc); 289 | case 290 | when buf in ('\') then 291 | varbuf := varbuf || buf || buf; v_count := v_count + 2; 292 | indx := indx + 1; 293 | buf := next_char(indx, jsrc); 294 | when buf in ('"', '/') then 295 | varbuf := varbuf || buf; v_count := v_count + 1; 296 | indx := indx + 1; 297 | buf := next_char(indx, jsrc); 298 | when buf = '''' then 299 | if(json_strict = false) then 300 | varbuf := varbuf || buf; v_count := v_count + 1; 301 | indx := indx + 1; 302 | buf := next_char(indx, jsrc); 303 | else 304 | s_error('strictmode - expected: " \ / b f n r t u ', tok); 305 | end if; 306 | when buf in ('b', 'f', 'n', 'r', 't') then 307 | --backspace b = U+0008 308 | --formfeed f = U+000C 309 | --newline n = U+000A 310 | --carret r = U+000D 311 | --tabulator t = U+0009 312 | case buf 313 | when 'b' then varbuf := varbuf || chr(8); 314 | when 'f' then varbuf := varbuf || chr(12); 315 | when 'n' then varbuf := varbuf || chr(10); 316 | when 'r' then varbuf := varbuf || chr(13); 317 | when 't' then varbuf := varbuf || chr(9); 318 | end case; 319 | --varbuf := varbuf || buf; 320 | v_count := v_count + 1; 321 | indx := indx + 1; 322 | buf := next_char(indx, jsrc); 323 | when buf = 'u' then 324 | --four hexidecimal chars 325 | declare 326 | four varchar2(4); 327 | begin 328 | four := next_char2(indx+1, jsrc, 4); 329 | wrong := FALSE; 330 | if(upper(substr(four, 1,1)) not in ('0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F','a','b','c','d','e','f')) then wrong := TRUE; end if; 331 | if(upper(substr(four, 2,1)) not in ('0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F','a','b','c','d','e','f')) then wrong := TRUE; end if; 332 | if(upper(substr(four, 3,1)) not in ('0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F','a','b','c','d','e','f')) then wrong := TRUE; end if; 333 | if(upper(substr(four, 4,1)) not in ('0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F','a','b','c','d','e','f')) then wrong := TRUE; end if; 334 | if(wrong) then 335 | s_error('expected: " \u([0-9][A-F]){4}', tok); 336 | end if; 337 | -- varbuf := varbuf || buf || four; 338 | varbuf := varbuf || '\'||four;--chr(to_number(four,'XXXX')); 339 | v_count := v_count + 5; 340 | indx := indx + 5; 341 | buf := next_char(indx, jsrc); 342 | end; 343 | else 344 | s_error('expected: " \ / b f n r t u ', tok); 345 | end case; 346 | else 347 | varbuf := varbuf || buf; v_count := v_count + 1; 348 | indx := indx + 1; 349 | buf := next_char(indx, jsrc); 350 | end if; 351 | end loop; 352 | 353 | if (buf is null) then 354 | s_error('string ending not found', tok); 355 | --debug('Premature string ending'); 356 | end if; 357 | 358 | --debug(varbuf); 359 | --dbms_output.put_line(varbuf); 360 | if(v_extended is not null) then 361 | updateClob(v_extended, unistr(varbuf)); 362 | tok.data_overflow := v_extended; 363 | tok.data := dbms_lob.substr(v_extended, 1, 32767); 364 | else 365 | tok.data := unistr(varbuf); 366 | end if; 367 | return indx; 368 | end lexString; 369 | 370 | ---------------------------------------------------------- 371 | -- lexer (private) 372 | -- 373 | -- scanner tokens: 374 | -- '{', '}', ',', ':', '[', ']', STRING, NUMBER, TRUE, FALSE, NULL 375 | -- 376 | FUNCTION lexer(jsrc IN OUT NOCOPY json_src) RETURN lTokens 377 | IS 378 | tokens lTokens; 379 | indx pls_integer := 1; 380 | tok_indx pls_integer := 1; 381 | buf varchar2(4); 382 | lin_no number := 1; 383 | col_no number := 0; 384 | BEGIN 385 | while (indx <= jsrc.len) loop 386 | --read into buf 387 | buf := next_char(indx, jsrc); 388 | col_no := col_no + 1; 389 | --convert to switch case 390 | case 391 | when buf = '{' then tokens(tok_indx) := mt('{', lin_no, col_no, null); tok_indx := tok_indx + 1; 392 | when buf = '}' then tokens(tok_indx) := mt('}', lin_no, col_no, null); tok_indx := tok_indx + 1; 393 | when buf = ',' then tokens(tok_indx) := mt(',', lin_no, col_no, null); tok_indx := tok_indx + 1; 394 | when buf = ':' then tokens(tok_indx) := mt(':', lin_no, col_no, null); tok_indx := tok_indx + 1; 395 | when buf = '[' then tokens(tok_indx) := mt('[', lin_no, col_no, null); tok_indx := tok_indx + 1; 396 | when buf = ']' then tokens(tok_indx) := mt(']', lin_no, col_no, null); tok_indx := tok_indx + 1; 397 | when buf = 't' then 398 | if(next_char2(indx, jsrc, 4) != 'true') then 399 | if(json_strict = false and REGEXP_LIKE(buf, '^[[:alpha:]]$', 'i')) then 400 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 401 | indx := lexName(jsrc, tokens(tok_indx), indx); 402 | col_no := col_no + length(tokens(tok_indx).data) + 1; 403 | tok_indx := tok_indx + 1; 404 | else 405 | s_error('Expected: ''true''', lin_no, col_no); 406 | end if; 407 | else 408 | tokens(tok_indx) := mt('TRUE', lin_no, col_no, null); tok_indx := tok_indx + 1; 409 | indx := indx + 3; 410 | col_no := col_no + 3; 411 | end if; 412 | when buf = 'n' then 413 | if(next_char2(indx, jsrc, 4) != 'null') then 414 | if(json_strict = false and REGEXP_LIKE(buf, '^[[:alpha:]]$', 'i')) then 415 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 416 | indx := lexName(jsrc, tokens(tok_indx), indx); 417 | col_no := col_no + length(tokens(tok_indx).data) + 1; 418 | tok_indx := tok_indx + 1; 419 | else 420 | s_error('Expected: ''null''', lin_no, col_no); 421 | end if; 422 | else 423 | tokens(tok_indx) := mt('NULL', lin_no, col_no, null); tok_indx := tok_indx + 1; 424 | indx := indx + 3; 425 | col_no := col_no + 3; 426 | end if; 427 | when buf = 'f' then 428 | if(next_char2(indx, jsrc, 5) != 'false') then 429 | if(json_strict = false and REGEXP_LIKE(buf, '^[[:alpha:]]$', 'i')) then 430 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 431 | indx := lexName(jsrc, tokens(tok_indx), indx); 432 | col_no := col_no + length(tokens(tok_indx).data) + 1; 433 | tok_indx := tok_indx + 1; 434 | else 435 | s_error('Expected: ''false''', lin_no, col_no); 436 | end if; 437 | else 438 | tokens(tok_indx) := mt('FALSE', lin_no, col_no, null); tok_indx := tok_indx + 1; 439 | indx := indx + 4; 440 | col_no := col_no + 4; 441 | end if; 442 | /* -- 9 = TAB, 10 = \n, 13 = \r (Linux = \n, Windows = \r\n, Mac = \r */ 443 | when (buf = Chr(10)) then --linux newlines 444 | lin_no := lin_no + 1; 445 | col_no := 0; 446 | 447 | when (buf = Chr(13)) then --Windows or Mac way 448 | lin_no := lin_no + 1; 449 | col_no := 0; 450 | if(jsrc.len >= indx +1) then -- better safe than sorry 451 | buf := next_char(indx+1, jsrc); 452 | if(buf = Chr(10)) then --\r\n 453 | indx := indx + 1; 454 | end if; 455 | end if; 456 | 457 | when (buf = CHR(9)) then null; --tabbing 458 | when (buf in ('-', '0', '1', '2', '3', '4', '5', '6', '7', '8', '9')) then --number 459 | tokens(tok_indx) := mt('NUMBER', lin_no, col_no, null); 460 | indx := lexNumber(jsrc, tokens(tok_indx), indx)-1; 461 | col_no := col_no + length(tokens(tok_indx).data); 462 | tok_indx := tok_indx + 1; 463 | when buf = '"' then --number 464 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 465 | indx := lexString(jsrc, tokens(tok_indx), indx, '"'); 466 | col_no := col_no + length(tokens(tok_indx).data) + 1; 467 | tok_indx := tok_indx + 1; 468 | when buf = '''' and json_strict = false then --number 469 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 470 | indx := lexString(jsrc, tokens(tok_indx), indx, ''''); 471 | col_no := col_no + length(tokens(tok_indx).data) + 1; --hovsa her 472 | tok_indx := tok_indx + 1; 473 | when json_strict = false and REGEXP_LIKE(buf, '^[[:alpha:]]$', 'i') then 474 | tokens(tok_indx) := mt('STRING', lin_no, col_no, null); 475 | indx := lexName(jsrc, tokens(tok_indx), indx); 476 | if(tokens(tok_indx).data_overflow is not null) then 477 | col_no := col_no + dbms_lob.getlength(tokens(tok_indx).data_overflow) + 1; 478 | else 479 | col_no := col_no + length(tokens(tok_indx).data) + 1; 480 | end if; 481 | tok_indx := tok_indx + 1; 482 | when json_strict = false and buf||next_char(indx+1, jsrc) = '/*' then --strip comments 483 | declare 484 | saveindx number := indx; 485 | un_esc clob; 486 | begin 487 | indx := indx + 1; 488 | loop 489 | indx := indx + 1; 490 | buf := next_char(indx, jsrc)||next_char(indx+1, jsrc); 491 | exit when buf = '*/'; 492 | exit when buf is null; 493 | end loop; 494 | 495 | if(indx = saveindx+2) then 496 | --enter unescaped mode 497 | --dbms_output.put_line('Entering unescaped mode'); 498 | un_esc := empty_clob(); 499 | dbms_lob.createtemporary(un_esc, true); 500 | indx := indx + 1; 501 | loop 502 | indx := indx + 1; 503 | buf := next_char(indx, jsrc)||next_char(indx+1, jsrc)||next_char(indx+2, jsrc)||next_char(indx+3, jsrc); 504 | exit when buf = '/**/'; 505 | if buf is null then 506 | s_error('Unexpected sequence /**/ to end unescaped data: '||buf, lin_no, col_no); 507 | end if; 508 | buf := next_char(indx, jsrc); 509 | dbms_lob.writeappend(un_esc, length(buf), buf); 510 | end loop; 511 | tokens(tok_indx) := mt('ESTRING', lin_no, col_no, null); 512 | tokens(tok_indx).data_overflow := un_esc; 513 | col_no := col_no + dbms_lob.getlength(un_esc) + 1; --note: line count won't work properly 514 | tok_indx := tok_indx + 1; 515 | indx := indx + 2; 516 | end if; 517 | 518 | indx := indx + 1; 519 | end; 520 | when buf = ' ' then null; --space 521 | else 522 | s_error('Unexpected char: '||buf, lin_no, col_no); 523 | end case; 524 | 525 | indx := indx + 1; 526 | end loop; 527 | 528 | return tokens; 529 | END lexer; 530 | 531 | 532 | -- 533 | -- END SCANNER 534 | -- *********** 535 | 536 | 537 | -- 538 | -- START PARSER 539 | -- ************ 540 | 541 | 542 | ---------------------------------------------------------- 543 | -- p_error (private) 544 | -- 545 | PROCEDURE p_error(text VARCHAR2, tok rToken) 546 | IS 547 | BEGIN 548 | raise_application_error(-20101, 'JSON Parser exception @ line: '||tok.line||' column: '||tok.col||' - '||text); 549 | END p_error; 550 | 551 | ---------------------------------------------------------- 552 | -- parseObj (private) 553 | -- 554 | PROCEDURE parseObj(tokens lTokens, indx IN OUT NOCOPY PLS_INTEGER, theParentID IN OUT BINARY_INTEGER, theLastID IN OUT BINARY_INTEGER, theNodes IN OUT NOCOPY jsonNodes) 555 | IS 556 | TYPE memmap IS TABLE OF NUMBER INDEX BY VARCHAR2(4000); -- i've read somewhere that this is not possible - but it is! 557 | mymap memmap; 558 | nullelemfound BOOLEAN := FALSE; 559 | 560 | --yyy obj json; 561 | obj jsonObject := jsonObject(); 562 | 563 | tok rToken; 564 | mem_name VARCHAR(4000); 565 | --yyy arr json_value_array := json_value_array(); 566 | arr jsonNodes := jsonNodes(); 567 | BEGIN 568 | debug('parseObj - begin'); 569 | 570 | -- what to expect? 571 | WHILE (indx <= tokens.count) LOOP 572 | tok := tokens(indx); 573 | debug('parseObj - type: '||tok.type_name); 574 | CASE tok.type_name 575 | WHEN 'STRING' THEN 576 | -- member 577 | mem_name := substr(tok.data, 1, 4000); 578 | BEGIN 579 | IF (mem_name IS NULL) THEN 580 | IF (nullelemfound) THEN 581 | p_error('Duplicate empty member: ', tok); 582 | ELSE 583 | nullelemfound := TRUE; 584 | END IF; 585 | ELSIF (mymap(mem_name) IS NOT NULL) THEN 586 | p_error('Duplicate member name: '||mem_name, tok); 587 | END IF; 588 | EXCEPTION 589 | WHEN no_data_found THEN 590 | mymap(mem_name) := 1; 591 | END; 592 | 593 | indx := indx + 1; 594 | IF (indx > tokens.count) THEN 595 | p_error('Unexpected end of input', tok); 596 | END IF; 597 | 598 | tok := tokens(indx); 599 | indx := indx + 1; 600 | IF (indx > tokens.count) THEN 601 | p_error('Unexpected end of input', tok); 602 | END IF; 603 | 604 | IF (tok.type_name = ':') THEN 605 | debug('parseObj - : found'); 606 | parseMem(tokens, indx, mem_name, 0, theParentID, theLastID, theNodes); 607 | ELSE 608 | p_error('Expected '':''', tok); 609 | END IF; 610 | 611 | --move indx forward if ',' is found 612 | IF (indx > tokens.count) THEN 613 | p_error('Unexpected end of input', tok); 614 | END IF; 615 | 616 | tok := tokens(indx); 617 | IF (tok.type_name = ',') THEN 618 | debug('found ,'); 619 | indx := indx + 1; 620 | tok := tokens(indx); 621 | IF (tok.type_name = '}') THEN --premature exit 622 | p_error('Premature exit in json object', tok); 623 | END IF; 624 | ELSIF (tok.type_name != '}') THEN 625 | p_error('A comma seperator is probably missing', tok); 626 | END IF; 627 | 628 | WHEN '}' THEN 629 | debug('parseObj - } found: returning '||arr.COUNT||' theNodes'); 630 | RETURN; 631 | 632 | ELSE 633 | p_error('Expected string or }', tok); 634 | 635 | END CASE; 636 | 637 | END LOOP; 638 | 639 | p_error('} not found', tokens(indx-1)); 640 | END parseObj; 641 | 642 | ---------------------------------------------------------- 643 | -- parseArr (private) 644 | -- 645 | PROCEDURE parseArr(tokens lTokens, indx IN OUT NOCOPY PLS_INTEGER, theParentID IN OUT BINARY_INTEGER, theLastID IN OUT BINARY_INTEGER, theNodes IN OUT NOCOPY jsonNodes) 646 | IS 647 | aNodeID BINARY_INTEGER; 648 | aLastID BINARY_INTEGER; 649 | tok rToken; 650 | aNode jsonNode := jsonNode(); 651 | BEGIN 652 | IF (indx > tokens.count) THEN 653 | p_error('more elements in array was excepted', tok); 654 | END IF; 655 | 656 | tok := tokens(indx); 657 | WHILE (tok.type_name != ']') LOOP 658 | 659 | CASE tok.type_name 660 | 661 | WHEN 'TRUE' THEN 662 | debug('parseArr - type: '||tok.type_name||' indx: '||indx); 663 | aNode := jsonNode(NULL, TRUE); 664 | aNode.par := theParentID; 665 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 666 | IF (theLastID IS NOT NULL) THEN 667 | theNodes(theLastID).nex := aNodeID; 668 | END IF; 669 | theLastID := aNodeID; 670 | 671 | WHEN 'FALSE' THEN 672 | debug('parseArr - type: '||tok.type_name||' indx: '||indx); 673 | aNode := jsonNode(NULL, FALSE); 674 | aNode.par := theParentID; 675 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 676 | IF (theLastID IS NOT NULL) THEN 677 | theNodes(theLastID).nex := aNodeID; 678 | END IF; 679 | theLastID := aNodeID; 680 | 681 | WHEN 'NULL' THEN 682 | debug('parseArr - type: '||tok.type_name||' indx: '||indx); 683 | aNode := jsonNode(NULL); 684 | aNode.par := theParentID; 685 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 686 | IF (theLastID IS NOT NULL) THEN 687 | theNodes(theLastID).nex := aNodeID; 688 | END IF; 689 | theLastID := aNodeID; 690 | 691 | WHEN 'STRING' THEN 692 | debug('parseArr - type: '||tok.type_name||' indx: '||indx||' value: '||CASE WHEN tok.data_overflow IS NOT NULL THEN tok.data_overflow ELSE tok.data END); 693 | aNode := jsonNode(NULL, CASE WHEN tok.data_overflow IS NOT NULL THEN tok.data_overflow ELSE tok.data END); 694 | aNode.par := theParentID; 695 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 696 | IF (theLastID IS NOT NULL) THEN 697 | theNodes(theLastID).nex := aNodeID; 698 | END IF; 699 | theLastID := aNodeID; 700 | 701 | WHEN 'ESTRING' THEN 702 | debug('parseArr - type: '||tok.type_name||' indx: '||indx||' value: '||tok.data_overflow); 703 | aNode := jsonNode(NULL, tok.data_overflow); 704 | aNode.par := theParentID; 705 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 706 | IF (theLastID IS NOT NULL) THEN 707 | theNodes(theLastID).nex := aNodeID; 708 | END IF; 709 | theLastID := aNodeID; 710 | 711 | WHEN 'NUMBER' THEN 712 | debug('parseArr - type: '||tok.type_name||' indx: '||indx||' value: '||TO_NUMBER(REPLACE(tok.data, '.', decimalpoint))); 713 | aNode := jsonNode(NULL, TO_NUMBER(REPLACE(tok.data, '.', decimalpoint))); 714 | aNode.par := theParentID; 715 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 716 | IF (theLastID IS NOT NULL) THEN 717 | theNodes(theLastID).nex := aNodeID; 718 | END IF; 719 | theLastID := aNodeID; 720 | 721 | WHEN '{' THEN 722 | debug('parseArr - type: '||tok.type_name||' indx: '||indx); 723 | 724 | aNode := jsonNode(); 725 | aNode.typ := 'O'; 726 | aNode.sub := theNodes.COUNT + 2; 727 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 728 | IF (theLastID IS NOT NULL) THEN 729 | theNodes(theLastID).nex := aNodeID; 730 | END IF; 731 | theLastID := aNodeID; 732 | theParentID := aNodeID; 733 | 734 | indx := indx + 1; 735 | aLastID := theLastID; 736 | theLastID := NULL; 737 | parseObj(tokens, indx, theParentID, theLastID, theNodes); 738 | -- if "theLastID" did not change, we must be dealing with an empty object that does actually not have any sub-nodes 739 | IF (theLastID IS NULL) THEN 740 | theNodes(aLastID).sub := NULL; 741 | END IF; 742 | theLastID := aLastID; 743 | aLastID := NULL; 744 | theParentID := NULL; 745 | 746 | WHEN '[' THEN 747 | debug('parseArr - type: '||tok.type_name||' indx: '||indx); 748 | 749 | aNode := jsonNode(); 750 | aNode.typ := 'A'; 751 | aNode.sub := theNodes.COUNT + 2; 752 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 753 | IF (theLastID IS NOT NULL) THEN 754 | theNodes(theLastID).nex := aNodeID; 755 | END IF; 756 | theLastID := aNodeID; 757 | theParentID := aNodeID; 758 | 759 | indx := indx + 1; 760 | aLastID := theLastID; 761 | theLastID := NULL; 762 | parseArr(tokens, indx, theParentID, theLastID, theNodes); 763 | -- if "theLastID" did not change, we must be dealing with an empty array that does actually not have any sub-nodes 764 | IF (theLastID IS NULL) THEN 765 | theNodes(aLastID).sub := NULL; 766 | END IF; 767 | theLastID := aLastID; 768 | aLastID := NULL; 769 | theParentID := NULL; 770 | 771 | ELSE 772 | p_error('Expected a value', tok); 773 | 774 | END CASE; 775 | 776 | indx := indx + 1; 777 | IF (indx > tokens.count) THEN 778 | p_error('] not found', tok); 779 | END IF; 780 | tok := tokens(indx); 781 | IF (tok.type_name = ',') THEN --advance 782 | indx := indx + 1; 783 | IF (indx > tokens.count) THEN 784 | p_error('more elements in array was excepted', tok); 785 | END IF; 786 | tok := tokens(indx); 787 | IF (tok.type_name = ']') THEN --premature exit 788 | p_error('Premature exit in array', tok); 789 | END IF; 790 | ELSIF (tok.type_name != ']') THEN --error 791 | p_error('Expected , or ]', tok); 792 | END IF; 793 | 794 | END LOOP; 795 | end parseArr; 796 | 797 | ---------------------------------------------------------- 798 | -- parseMem (private) 799 | -- 800 | PROCEDURE parseMem(tokens lTokens, indx IN OUT PLS_INTEGER, mem_name VARCHAR2, mem_indx NUMBER, theParentID IN OUT BINARY_INTEGER, theLastID IN OUT BINARY_INTEGER, theNodes IN OUT NOCOPY jsonNodes) 801 | IS 802 | tok rToken; 803 | aNodeID BINARY_INTEGER; 804 | aLastID BINARY_INTEGER; 805 | aNode jsonNode := jsonNode(); 806 | BEGIN 807 | tok := tokens(indx); 808 | 809 | CASE tok.type_name 810 | 811 | WHEN 'TRUE' THEN 812 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name); 813 | aNode := jsonNode(mem_name, TRUE); 814 | aNode.par := theParentID; 815 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 816 | IF (theLastID IS NOT NULL) THEN 817 | theNodes(theLastID).nex := aNodeID; 818 | END IF; 819 | theLastID := aNodeID; 820 | 821 | WHEN 'FALSE' THEN 822 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name); 823 | aNode := jsonNode(mem_name, FALSE); 824 | aNode.par := theParentID; 825 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 826 | IF (theLastID IS NOT NULL) THEN 827 | theNodes(theLastID).nex := aNodeID; 828 | END IF; 829 | theLastID := aNodeID; 830 | 831 | WHEN 'NULL' THEN 832 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name); 833 | aNode := jsonNode(mem_name); 834 | aNode.par := theParentID; 835 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 836 | IF (theLastID IS NOT NULL) THEN 837 | theNodes(theLastID).nex := aNodeID; 838 | END IF; 839 | theLastID := aNodeID; 840 | 841 | WHEN 'STRING' THEN 842 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name||' value: '||CASE WHEN tok.data_overflow IS NOT NULL THEN tok.data_overflow ELSE tok.data END); 843 | aNode := jsonNode(mem_name, CASE WHEN tok.data_overflow IS NOT NULL THEN tok.data_overflow ELSE tok.data END); 844 | aNode.par := theParentID; 845 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 846 | IF (theLastID IS NOT NULL) THEN 847 | theNodes(theLastID).nex := aNodeID; 848 | END IF; 849 | theLastID := aNodeID; 850 | 851 | WHEN 'ESTRING' THEN 852 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name||' value: '||tok.data_overflow); 853 | aNode := jsonNode(mem_name, tok.data_overflow); 854 | aNode.par := theParentID; 855 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 856 | IF (theLastID IS NOT NULL) THEN 857 | theNodes(theLastID).nex := aNodeID; 858 | END IF; 859 | theLastID := aNodeID; 860 | 861 | WHEN 'NUMBER' THEN 862 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name||' value: '||TO_NUMBER(REPLACE(tok.data, '.', decimalpoint))); 863 | aNode := jsonNode(mem_name, TO_NUMBER(REPLACE(tok.data, '.', decimalpoint))); 864 | aNode.par := theParentID; 865 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 866 | IF (theLastID IS NOT NULL) THEN 867 | theNodes(theLastID).nex := aNodeID; 868 | END IF; 869 | theLastID := aNodeID; 870 | 871 | WHEN '{' THEN 872 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name); 873 | 874 | aNode := jsonNode(); 875 | aNode.typ := 'O'; 876 | aNode.nam := mem_name; 877 | aNode.sub := theNodes.COUNT + 2; 878 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 879 | IF (theLastID IS NOT NULL) THEN 880 | theNodes(theLastID).nex := aNodeID; 881 | END IF; 882 | theLastID := aNodeID; 883 | theParentID := aNodeID; 884 | 885 | indx := indx + 1; 886 | aLastID := theLastID; 887 | theLastID := NULL; 888 | parseObj(tokens, indx, theParentID, theLastID, theNodes); 889 | -- if "theLastID" did not change, we must be dealing with an empty object that does actually not have any sub-nodes 890 | IF (theLastID IS NULL) THEN 891 | theNodes(aLastID).sub := NULL; 892 | END IF; 893 | theLastID := aLastID; 894 | aLastID := NULL; 895 | theParentID := NULL; 896 | 897 | WHEN '[' THEN 898 | debug('parseMem - type: '||tok.type_name||' name: '||mem_name); 899 | 900 | aNode := jsonNode(); 901 | aNode.typ := 'A'; 902 | aNode.nam := mem_name; 903 | aNode.sub := theNodes.COUNT + 2; 904 | aNodeID := json_utils.addNode(theNodes=>theNodes, theNode=>aNode); 905 | IF (theLastID IS NOT NULL) THEN 906 | theNodes(theLastID).nex := aNodeID; 907 | END IF; 908 | theLastID := aNodeID; 909 | theParentID := aNodeID; 910 | 911 | indx := indx + 1; 912 | aLastID := theLastID; 913 | theLastID := NULL; 914 | parseArr(tokens, indx, theParentID, theLastID, theNodes); 915 | -- if "theLastID" did not change, we must be dealing with an empty array that does actually not have any sub-nodes 916 | IF (theLastID IS NULL) THEN 917 | theNodes(aLastID).sub := NULL; 918 | END IF; 919 | theLastID := aLastID; 920 | aLastID := NULL; 921 | theParentID := NULL; 922 | 923 | ELSE 924 | p_error('Found '||tok.type_name, tok); 925 | 926 | END CASE; 927 | 928 | indx := indx + 1; 929 | END parseMem; 930 | 931 | ---------------------------------------------------------- 932 | -- parse_list 933 | -- 934 | FUNCTION parse_list(str CLOB) RETURN jsonNodes 935 | IS 936 | tokens lTokens; 937 | --yyy obj json_list; 938 | obj jsonNodes := jsonNodes(); 939 | indx PLS_INTEGER := 1; 940 | jsrc json_src; 941 | BEGIN 942 | debug('parse_list'); 943 | updateDecimalPoint(); 944 | jsrc := prepareClob(str); 945 | tokens := lexer(jsrc); 946 | IF (tokens(indx).type_name = '[') THEN 947 | indx := indx + 1; 948 | --yyy obj := parseArr(tokens, indx); 949 | ELSE 950 | raise_application_error(-20101, 'JSON List Parser exception - no [ start found'); 951 | END IF; 952 | IF (tokens.count != indx) THEN 953 | p_error('] should end the JSON List object', tokens(indx)); 954 | END IF; 955 | 956 | RETURN obj; 957 | END parse_list; 958 | 959 | ---------------------------------------------------------- 960 | -- parser 961 | -- 962 | FUNCTION parser(str CLOB) RETURN jsonNodes 963 | IS 964 | tokens lTokens; 965 | obj jsonNodes := jsonNodes(); 966 | 967 | indx PLS_INTEGER := 1; 968 | jsrc json_src; 969 | i BINARY_INTEGER; 970 | aParentID BINARY_INTEGER := NULL; 971 | aLastID BINARY_INTEGER := NULL; 972 | BEGIN 973 | updateDecimalPoint(); 974 | jsrc := prepareClob(str); 975 | 976 | tokens := lexer(jsrc); 977 | 978 | -- dump tokens 979 | /* 980 | dbms_output.put_line('----------LEXER-S----------'); 981 | i := tokens.FIRST; 982 | WHILE (i IS NOT NULL) LOOP 983 | dbms_output.put_line(i||'. type=('||tokens(i).type_name||') type=('||tokens(i).data||') type=('||tokens(i).data_overflow||')'); 984 | i := tokens.NEXT(i); 985 | END LOOP; 986 | dbms_output.put_line('----------LEXER-E----------'); 987 | */ 988 | 989 | IF (tokens(indx).type_name = '{') THEN 990 | indx := indx + 1; 991 | --yyy obj := parseObj(tokens, indx); 992 | parseObj(tokens, indx, aParentID, aLastID, obj); 993 | ELSE 994 | raise_application_error(-20101, 'JSON Parser exception - no { start found'); 995 | END IF; 996 | IF (tokens.count != indx) THEN 997 | p_error('} should end the JSON object', tokens(indx)); 998 | END IF; 999 | 1000 | RETURN obj; 1001 | END parser; 1002 | 1003 | ---------------------------------------------------------- 1004 | -- parse_any 1005 | -- 1006 | FUNCTION parse_any(str CLOB) RETURN /*yyy jsonValue*/jsonNodes 1007 | IS 1008 | tokens lTokens; 1009 | --yyy obj json_list; 1010 | obj jsonArray := jsonArray(); 1011 | indx PLS_INTEGER := 1; 1012 | jsrc json_src; 1013 | BEGIN 1014 | debug('parse_any'); 1015 | jsrc := prepareClob(str); 1016 | tokens := lexer(jsrc); 1017 | tokens(tokens.count+1).type_name := ']'; 1018 | --yyy obj := parseArr(tokens, indx); 1019 | IF (tokens.count != indx) THEN 1020 | p_error('] should end the JSON List object', tokens(indx)); 1021 | END IF; 1022 | 1023 | --yyy return obj.head(); 1024 | RETURN NULL; 1025 | END parse_any; 1026 | 1027 | END json_parser; 1028 | / 1029 | -------------------------------------------------------------------------------- /json_parser.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_parser IS 3 | 4 | ------------ 5 | -- OVERVIEW 6 | -- 7 | -- ... 8 | -- 9 | -- 10 | 11 | ----------- 12 | -- EXAMPLE 13 | -- 14 | -- 15 | 16 | ------------- 17 | -- RESOURCES 18 | -- 19 | -- 20 | 21 | ---------------------------------------------------------- 22 | -- GLOBAL PUBLIC TYPES 23 | ---------------------------------------------------------- 24 | 25 | -- scanner tokens: '{', '}', ',', ':', '[', ']', STRING, NUMBER, TRUE, FALSE, NULL 26 | TYPE rToken IS RECORD 27 | ( 28 | type_name VARCHAR2(7), 29 | line PLS_INTEGER, 30 | col PLS_INTEGER, 31 | data VARCHAR2(32767), 32 | data_overflow clob 33 | ); 34 | 35 | TYPE lTokens IS TABLE OF rToken INDEX BY PLS_INTEGER; 36 | TYPE json_src IS RECORD (len NUMBER, offset NUMBER, src VARCHAR2(32767), s_clob CLOB); 37 | 38 | ---------------------------------------------------------- 39 | -- GLOBAL PUBLIC CONSTANTS 40 | ---------------------------------------------------------- 41 | 42 | --------------------------------------------------------- 43 | -- GLOBAL VARIABLES 44 | ---------------------------------------------------------- 45 | 46 | json_strict BOOLEAN NOT NULL := FALSE; 47 | 48 | ---------------------------------------------------------- 49 | -- GLOBAL PUBLIC MODULES 50 | ---------------------------------------------------------- 51 | 52 | FUNCTION parser(str CLOB) RETURN jsonNodes; 53 | FUNCTION parse_list(str CLOB) RETURN jsonNodes; 54 | FUNCTION parse_any(str CLOB) RETURN jsonNodes; 55 | 56 | END json_parser; 57 | / 58 | -------------------------------------------------------------------------------- /json_sql.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY json_sql 3 | IS 4 | 5 | TYPE HandleType IS RECORD 6 | ( 7 | cursorID INTEGER, 8 | description dbms_sql.desc_tab, 9 | stringColumn VARCHAR2(4000), 10 | numberColumn NUMBER, 11 | dateColumn DATE 12 | ); 13 | 14 | FUNCTION openCursor(rc IN OUT SYS_REFCURSOR) RETURN HandleType; 15 | FUNCTION openCursor(sqlCmd VARCHAR2, sqlBind jsonObject DEFAULT NULL_OBJECT) RETURN HandleType; 16 | PROCEDURE bind(theCursor IN INTEGER, theBinding jsonObject); 17 | PROCEDURE describeAndDefine(theHandle IN OUT NOCOPY HandleType); 18 | FUNCTION process(theHandle IN OUT NOCOPY HandleType, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject; 19 | PROCEDURE closeCursor(theHandle IN OUT NOCOPY HandleType); 20 | 21 | ---------------------------------------------------------- 22 | -- get (SYS_REFCURSOR) 23 | -- 24 | FUNCTION get(rc IN OUT SYS_REFCURSOR, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject 25 | IS 26 | aHandle HandleType; 27 | aObject jsonObject := jsonObject(); 28 | BEGIN 29 | -- open cursor 30 | aHandle := openCursor(rc=>rc); 31 | 32 | -- process cursor 33 | aObject := process(theHandle=>aHandle, format=>format); 34 | 35 | -- close cursor 36 | closeCursor(aHandle); 37 | 38 | RETURN aObject; 39 | END get; 40 | 41 | ---------------------------------------------------------- 42 | -- get 43 | -- 44 | FUNCTION get(sqlCmd VARCHAR2, sqlBind jsonObject DEFAULT NULL_OBJECT, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject 45 | IS 46 | aHandle HandleType; 47 | aObject jsonObject := jsonObject(); 48 | BEGIN 49 | -- open cursor 50 | aHandle := openCursor(sqlCmd=>sqlCmd, sqlBind=>sqlBind); 51 | 52 | -- process cursor 53 | aObject := process(theHandle=>aHandle, format=>format); 54 | 55 | -- close cursor 56 | closeCursor(aHandle); 57 | 58 | RETURN aObject; 59 | END get; 60 | 61 | ---------------------------------------------------------- 62 | -- Execute sql statement and output a json structure 63 | -- 64 | PROCEDURE htp(sqlCmd VARCHAR2, sqlBind IN VARCHAR2 DEFAULT NULL, format IN VARCHAR2 DEFAULT FORMAT_TAB) 65 | IS 66 | aBinding jsonObject := jsonObject(); 67 | BEGIN 68 | -- parse 69 | IF (sqlBind IS NOT NULL) THEN 70 | aBinding := jsonObject(TO_CLOB(sqlBind)); 71 | END IF; 72 | 73 | -- process and output 74 | get(sqlCmd=>sqlCmd, sqlBind=>aBinding, format=>UPPER(format)).htp(); 75 | END htp; 76 | 77 | ---------------------------------------------------------- 78 | -- openCursor (private) 79 | -- 80 | FUNCTION openCursor(rc IN OUT SYS_REFCURSOR) RETURN HandleType 81 | IS 82 | aHandle HandleType; 83 | BEGIN 84 | -- open cursor 85 | aHandle.cursorID := dbms_sql.to_cursor_number(rc=>rc); 86 | 87 | -- describe and define columns 88 | describeAndDefine(theHandle=>aHandle); 89 | 90 | RETURN aHandle; 91 | END openCursor; 92 | 93 | ---------------------------------------------------------- 94 | -- openCursor (private) 95 | -- 96 | FUNCTION openCursor(sqlCmd VARCHAR2, sqlBind jsonObject DEFAULT NULL_OBJECT) RETURN HandleType 97 | IS 98 | aHandle HandleType; 99 | aStatus INTEGER; 100 | BEGIN 101 | -- open cursor 102 | aHandle.cursorID := dbms_sql.open_cursor; 103 | 104 | -- parse statement 105 | dbms_sql.parse(aHandle.cursorID, sqlCmd, dbms_sql.native); 106 | 107 | -- bindings 108 | bind(aHandle.cursorID, sqlBind); 109 | 110 | -- describe and define columns 111 | describeAndDefine(theHandle=>aHandle); 112 | 113 | -- execute statement 114 | aStatus := dbms_sql.execute(aHandle.cursorID); 115 | 116 | RETURN aHandle; 117 | END openCursor; 118 | 119 | ---------------------------------------------------------- 120 | -- bind (private) 121 | -- 122 | PROCEDURE bind(theCursor IN INTEGER, theBinding jsonObject) 123 | IS 124 | aKeys jsonKeys := theBinding.get_keys(); 125 | aKey VARCHAR2(32767); 126 | aValue jsonValue := jsonValue(); 127 | BEGIN 128 | FOR i IN 1 .. aKeys.COUNT LOOP 129 | aKey := aKeys(i); 130 | aValue := theBinding.get(aKey); 131 | 132 | IF (aValue.get_type() = 'NUMBER') THEN 133 | dbms_sql.bind_variable(theCursor, ':'||aKey, aValue.get_number()); 134 | ELSIF (theBinding.get(aKey).get_type() = 'STRING') THEN 135 | dbms_sql.bind_variable(theCursor, ':'||aKey, aValue.get_string()); 136 | ELSE 137 | RAISE VALUE_ERROR; 138 | END IF; 139 | END LOOP; 140 | END bind; 141 | 142 | ---------------------------------------------------------- 143 | -- describeAndDefine (private) 144 | -- 145 | PROCEDURE describeAndDefine(theHandle IN OUT NOCOPY HandleType) 146 | IS 147 | aCount INTEGER; 148 | aType INTEGER; 149 | BEGIN 150 | 151 | -- describe columns 152 | dbms_sql.describe_columns(theHandle.cursorID, aCount, theHandle.description); 153 | 154 | -- define columns 155 | FOR i IN 1 .. aCount LOOP 156 | aType := theHandle.description(i).col_type; 157 | IF (aType IN (1, 112)) THEN 158 | dbms_sql.define_column(theHandle.cursorID, i, theHandle.stringColumn, 4000); 159 | ELSIF (aType = 2) THEN 160 | dbms_sql.define_column(theHandle.cursorID, i, theHandle.numberColumn); 161 | ELSIF (aType = 12) THEN 162 | dbms_sql.define_column(theHandle.cursorID, i, theHandle.dateColumn); 163 | END IF; 164 | END LOOP; 165 | END describeAndDefine; 166 | 167 | ---------------------------------------------------------- 168 | -- process (private) 169 | -- 170 | FUNCTION process(theHandle IN OUT NOCOPY HandleType, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject 171 | IS 172 | aName VARCHAR2(32767); 173 | aNames jsonArray := jsonArray(); 174 | aRowObj jsonObject := jsonObject(); 175 | aRowArr jsonArray := jsonArray(); 176 | aRows jsonArray := jsonArray(); 177 | aObject jsonObject := jsonObject(); 178 | BEGIN 179 | IF (format NOT IN (FORMAT_OBJ, FORMAT_TAB)) THEN 180 | RAISE VALUE_ERROR; 181 | END IF; 182 | 183 | -- column names 184 | IF (format = FORMAT_TAB) THEN 185 | FOR i IN 1 .. theHandle.description.COUNT LOOP 186 | IF (theHandle.description(i).col_type in (1, 96)) THEN 187 | aNames.append(theHandle.description(i).col_name); 188 | -- number 189 | ELSIF (theHandle.description(i).col_type = 2) THEN 190 | aNames.append(theHandle.description(i).col_name); 191 | -- date 192 | ELSIF (theHandle.description(i).col_type = 12) THEN 193 | aNames.append(theHandle.description(i).col_name); 194 | END IF; 195 | END LOOP; 196 | END IF; 197 | 198 | -- process rows 199 | WHILE (dbms_sql.fetch_rows(theHandle.cursorID) > 0) LOOP 200 | aRowObj := jsonObject(); 201 | aRowArr := jsonArray(); 202 | 203 | -- process columns 204 | FOR i IN 1 .. theHandle.description.COUNT LOOP 205 | 206 | -- column name 207 | aName := theHandle.description(i).col_name; 208 | 209 | -- string 210 | IF (theHandle.description(i).col_type in (1, 96)) THEN 211 | dbms_sql.column_value(theHandle.cursorID, i, theHandle.stringColumn); 212 | IF (format = FORMAT_OBJ) THEN 213 | aRowObj.put(aName, theHandle.stringColumn); 214 | ELSE 215 | aRowArr.append(theHandle.stringColumn); 216 | END IF; 217 | -- number 218 | ELSIF (theHandle.description(i).col_type = 2) THEN 219 | dbms_sql.column_value(theHandle.cursorID, i, theHandle.numberColumn); 220 | IF (format = FORMAT_OBJ) THEN 221 | aRowObj.put(aName, theHandle.numberColumn); 222 | ELSE 223 | aRowArr.append(theHandle.numberColumn); 224 | END IF; 225 | -- date 226 | ELSIF (theHandle.description(i).col_type = 12) THEN 227 | dbms_sql.column_value(theHandle.cursorID, i, theHandle.dateColumn); 228 | IF (format = FORMAT_OBJ) THEN 229 | aRowObj.put(aName, theHandle.dateColumn); 230 | ELSE 231 | aRowArr.append(theHandle.dateColumn); 232 | END IF; 233 | END IF; 234 | 235 | END LOOP; 236 | 237 | IF (format = FORMAT_OBJ) THEN 238 | aRows.append(aRowObj); 239 | ELSE 240 | aRows.append(aRowArr); 241 | END IF; 242 | END LOOP; 243 | 244 | IF (format = FORMAT_OBJ) THEN 245 | aObject.put('rows', aRows.to_jsonValue()); 246 | ELSE 247 | aObject.put('cols', aNames.to_jsonValue()); 248 | aObject.put('rows', aRows.to_jsonValue()); 249 | END IF; 250 | 251 | RETURN aObject; 252 | END process; 253 | 254 | ---------------------------------------------------------- 255 | -- closeCursor (private) 256 | -- 257 | PROCEDURE closeCursor(theHandle IN OUT NOCOPY HandleType) 258 | IS 259 | BEGIN 260 | IF (dbms_sql.is_open(theHandle.cursorID)) THEN 261 | dbms_sql.close_cursor(theHandle.cursorID); 262 | END IF; 263 | theHandle.cursorID := NULL; 264 | theHandle.description.DELETE; 265 | END closeCursor; 266 | 267 | END json_sql; 268 | / 269 | -------------------------------------------------------------------------------- /json_sql.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_sql 3 | IS 4 | 5 | ------------ 6 | -- OVERVIEW 7 | -- 8 | -- This package allows to dynamically generate a json representation of the rows in a select. 9 | -- 10 | -- 11 | 12 | ----------- 13 | -- EXAMPLE 14 | -- 15 | -- 2) Simple select 16 | -- 17 | -- 2.1) from code 18 | -- BEGIN 19 | -- json_sql.htp('select * from user_tables order by table_name'); 20 | -- END; 21 | -- 22 | -- 2.2) from browser 23 | -- json_sql.htp?sqlCmd=select * from user_tables order by table_name 24 | -- 25 | -- 26 | -- 3) Select with bind variables and format rows as objects 27 | -- 28 | -- 3.1) from code 29 | -- DECLARE 30 | -- aBind jsonObject := jsonObject(); 31 | -- BEGIN 32 | -- aBind.put('name', 'F'); 33 | -- json_sql.get(sqlCmd=>'select * from user_tables where UPPER(table_name) > :name', sqlBind=>aBind, format=>json_sql.FORMAT_OBJ).htp(); 34 | -- END; 35 | -- 36 | -- 3.2) from browser 37 | -- json_sql.htp?sqlCmd=select+*+from+user_tables+where+UPPER(table_name)+%3e+%3aname&sqlbind={"name":"F"}&format=obj 38 | -- 39 | -- 40 | 41 | ------------- 42 | -- RESOURCES 43 | -- 44 | -- 45 | 46 | ---------------------------------------------------------- 47 | -- GLOBAL PUBLIC EXCEPTIONS 48 | ---------------------------------------------------------- 49 | 50 | ---------------------------------------------------------- 51 | -- GLOBAL PUBLIC TYPES 52 | ---------------------------------------------------------- 53 | 54 | ---------------------------------------------------------- 55 | -- GLOBAL PUBLIC CONSTANTS 56 | ---------------------------------------------------------- 57 | 58 | -- format 59 | FORMAT_TAB CONSTANT VARCHAR2(3) := 'TAB'; 60 | FORMAT_OBJ CONSTANT VARCHAR2(3) := 'OBJ'; 61 | 62 | -- null binding 63 | NULL_OBJECT CONSTANT jsonObject := jsonObject(); 64 | 65 | ---------------------------------------------------------- 66 | -- GLOBAL PUBLIC ENUMERATIONS 67 | ---------------------------------------------------------- 68 | 69 | ---------------------------------------------------------- 70 | -- GLOBAL PUBLIC VARIABLES 71 | ---------------------------------------------------------- 72 | 73 | ---------------------------------------------------------- 74 | -- GLOBAL PUBLIC MODULES 75 | ---------------------------------------------------------- 76 | 77 | ---------------------------------------------------------- 78 | -- Execute SYS_REFCURSOR and output a json structure 79 | -- 80 | FUNCTION get(rc IN OUT SYS_REFCURSOR, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject; 81 | 82 | ---------------------------------------------------------- 83 | -- Execute sql statement and return a josn object 84 | -- 85 | FUNCTION get(sqlCmd VARCHAR2, sqlBind jsonObject DEFAULT NULL_OBJECT, format IN VARCHAR2 DEFAULT FORMAT_TAB) RETURN jsonObject; 86 | 87 | ---------------------------------------------------------- 88 | -- Execute sql statement and output a json structure 89 | -- 90 | PROCEDURE htp(sqlCmd VARCHAR2, sqlBind IN VARCHAR2 DEFAULT NULL, format IN VARCHAR2 DEFAULT FORMAT_TAB); 91 | 92 | END json_sql; 93 | / 94 | -------------------------------------------------------------------------------- /json_utils.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY json_utils 3 | IS 4 | 5 | outputOptions OutputOptionsType; 6 | 7 | PROCEDURE copySubNodes(theTarget IN OUT NOCOPY jsonNodes, theFirstID IN OUT NOCOPY BINARY_INTEGER, theParentID IN BINARY_INTEGER, theSource IN jsonNodes, theFirstSourceID IN BINARY_INTEGER); 8 | FUNCTION boolean_to_json(theBoolean IN NUMBER) RETURN VARCHAR2; 9 | FUNCTION number_to_json(theNumber IN NUMBER) RETURN VARCHAR2; 10 | FUNCTION get_gap(theIndentation IN INTEGER) RETURN VARCHAR2; 11 | PROCEDURE escapeLOB(theInputLob IN CLOB, theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theAsciiOutput IN BOOLEAN DEFAULT TRUE, theEscapeSolitus IN BOOLEAN DEFAULT FALSE); 12 | 13 | ---------------------------------------------------------- 14 | -- get_default_options 15 | -- 16 | FUNCTION get_default_options RETURN outputOptionsType 17 | IS 18 | aOptions outputOptionsType; 19 | BEGIN 20 | RETURN aOptions; 21 | END get_default_options; 22 | 23 | ---------------------------------------------------------- 24 | -- get_options 25 | -- 26 | FUNCTION get_options RETURN outputOptionsType 27 | IS 28 | BEGIN 29 | RETURN outputOptions; 30 | END get_options; 31 | 32 | ---------------------------------------------------------- 33 | -- set_options 34 | -- 35 | PROCEDURE set_options(theOptions IN outputOptionsType) 36 | IS 37 | BEGIN 38 | IF (theOptions.newline_char NOT IN (EOL_LF, EOL_CR, EOL_CRLF)) THEN 39 | raise_application_error(-20100, 'Invalid newline style. Use EOL constant', TRUE); 40 | END IF; 41 | 42 | IF (theOptions.indentation_char NOT IN (IND_TAB, IND_SPACE_1, IND_SPACE_2, IND_SPACE_3, IND_SPACE_4)) THEN 43 | raise_application_error(-20100, 'Invalid indentation style. Use IND constant', TRUE); 44 | END IF; 45 | 46 | outputOptions := theOptions; 47 | END set_options; 48 | 49 | ---------------------------------------------------------- 50 | -- get_default_output_options 51 | -- 52 | FUNCTION get_default_output_options RETURN OutputOptionsType 53 | IS 54 | aOptions OutputOptionsType; 55 | BEGIN 56 | RETURN aOptions; 57 | END get_default_output_options; 58 | 59 | ---------------------------------------------------------- 60 | -- add_string 61 | -- 62 | PROCEDURE add_string(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theValue IN VARCHAR2) 63 | IS 64 | BEGIN 65 | IF (LENGTHB(theValue) > 32767 - LENGTHB(theStrBuf)) THEN 66 | dbms_lob.append(dest_lob=>theLobBuf, src_lob=>TO_CLOB(theStrBuf)); 67 | theStrBuf := theValue; 68 | ELSE 69 | theStrBuf := theStrBuf || theValue; 70 | END IF; 71 | END add_string; 72 | 73 | ---------------------------------------------------------- 74 | -- add_clob 75 | -- 76 | PROCEDURE add_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theValue IN CLOB) 77 | IS 78 | BEGIN 79 | PRAGMA INLINE (flush_clob, 'YES'); 80 | flush_clob(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf); 81 | 82 | dbms_lob.append(dest_lob=>theLobBuf, src_lob=>theValue); 83 | END add_clob; 84 | 85 | ---------------------------------------------------------- 86 | -- erase_clob 87 | -- 88 | PROCEDURE erase_clob(theLobBuf IN OUT NOCOPY CLOB) 89 | IS 90 | BEGIN 91 | IF (dbms_lob.getlength(lob_loc=>theLobBuf) > 0) THEN 92 | dbms_lob.trim(lob_loc=>theLobBuf, newlen=>0); 93 | END IF; 94 | END erase_clob; 95 | 96 | ---------------------------------------------------------- 97 | -- flush_clob 98 | -- 99 | PROCEDURE flush_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2) 100 | IS 101 | BEGIN 102 | IF (LENGTHB(theStrBuf) > 0) THEN 103 | dbms_lob.append(dest_lob=>theLobBuf, src_lob=>TO_CLOB(theStrBuf)); 104 | END IF; 105 | 106 | theStrBuf := NULL; 107 | END flush_clob; 108 | 109 | ---------------------------------------------------------- 110 | -- get the number of nodes 111 | -- 112 | FUNCTION getNodeCount(theNodes IN jsonNodes) RETURN BINARY_INTEGER 113 | IS 114 | i BINARY_INTEGER := theNodes.FIRST; 115 | c BINARY_INTEGER := 0; 116 | BEGIN 117 | WHILE (i IS NOT NULL) LOOP 118 | c := c + 1; 119 | i := theNodes(i).nex; 120 | END LOOP; 121 | 122 | RETURN c; 123 | END getNodeCount; 124 | 125 | ---------------------------------------------------------- 126 | -- getNodeIDByName 127 | -- 128 | FUNCTION getNodeIDByName(theNodes IN jsonNodes, thePropertyName IN VARCHAR2) RETURN BINARY_INTEGER 129 | IS 130 | i BINARY_INTEGER := theNodes.FIRST; 131 | BEGIN 132 | WHILE (i IS NOT NULL) LOOP 133 | IF (theNodes(i).nam = thePropertyName) THEN 134 | RETURN i; 135 | END IF; 136 | i := theNodes(i).nex; 137 | END LOOP; 138 | 139 | RETURN NULL; 140 | END getNodeIDByName; 141 | 142 | ---------------------------------------------------------- 143 | -- getNodeIDByIndex 144 | -- 145 | FUNCTION getNodeIDByIndex(theNodes IN jsonNodes, thePropertyIndex IN NUMBER) RETURN BINARY_INTEGER 146 | IS 147 | i BINARY_INTEGER := theNodes.FIRST; 148 | c BINARY_INTEGER := 0; 149 | BEGIN 150 | WHILE (i IS NOT NULL) LOOP 151 | c := c + 1; 152 | IF (c = thePropertyIndex) THEN 153 | RETURN i; 154 | END IF; 155 | i := theNodes(i).nex; 156 | END LOOP; 157 | 158 | RETURN NULL; 159 | END getNodeIDByIndex; 160 | 161 | ---------------------------------------------------------- 162 | -- validate 163 | -- 164 | PROCEDURE validate(theNodes IN OUT NOCOPY jsonNodes) 165 | IS 166 | n jsonNode; 167 | i BINARY_INTEGER; 168 | 169 | FUNCTION equal(theFirstID IN NUMBER, theSecondID IN NUMBER) RETURN BOOLEAN 170 | IS 171 | BEGIN 172 | IF (theFirstID IS NULL AND theSecondID IS NULL) THEN 173 | RETURN TRUE; 174 | ELSE 175 | RETURN (theFirstID = theSecondID); 176 | END IF; 177 | END equal; 178 | 179 | PROCEDURE error(theNodeID IN NUMBER, text VARCHAR2) 180 | IS 181 | BEGIN 182 | raise_application_error(-20100, 'JSON Validator exception @ node: '||theNodeID||' - '||text, TRUE); 183 | END error; 184 | BEGIN 185 | i := theNodes.FIRST; 186 | WHILE (i IS NOT NULL) LOOP 187 | n := theNodes(i); 188 | 189 | -- node references must (at least) exist 190 | IF (n.nex IS NOT NULL AND NOT theNodes.EXISTS(n.nex)) THEN 191 | error(i, 'Next node ('||n.nex||') does not exist'); 192 | END IF; 193 | IF (n.par IS NOT NULL AND NOT theNodes.EXISTS(n.par)) THEN 194 | error(i, 'Parent node ('||n.par||') does not exist'); 195 | END IF; 196 | IF (n.sub IS NOT NULL AND NOT theNodes.EXISTS(n.sub)) THEN 197 | error(i, 'Sub node ('||n.sub||') does not exist'); 198 | END IF; 199 | 200 | -- validations if we have a next node 201 | IF (n.nex IS NOT NULL) THEN 202 | IF (NOT equal(n.par, theNodes(n.nex).par)) THEN 203 | error(i, 'A node and its next node must have the same (or no) parent'); 204 | END IF; 205 | END IF; 206 | 207 | -- nodes with sub nodes 208 | IF (n.sub IS NOT NULL AND theNodes(n.sub).par != i) THEN 209 | error(i, 'Sub node ('||n.sub||') does not have a correct reference to the parent ('||theNodes(n.sub).par||')'); 210 | END IF; 211 | 212 | -- nodes with a parent... 213 | IF (n.par IS NOT NULL) THEN 214 | -- must have a parent that points to a sub node with the same parent as we have 215 | IF (theNodes(n.par).sub IS NULL OR theNodes(theNodes(n.par).sub).par != n.par) THEN 216 | error(i, 'Sub node ('||theNodes(n.par).sub||') of our parent node ('||n.par||') does not have a correct reference ('||theNodes(theNodes(n.par).sub).par||') to our parent ('||n.par||')'); 217 | END IF; 218 | END IF; 219 | 220 | -- sub nodes of an object node 221 | IF (n.par IS NOT NULL AND theNodes(n.par).typ = json_utils.NODE_TYPE_OBJECT AND n.nam IS NULL) THEN 222 | error(i, 'Sub nodes of an object node must have a property name'); 223 | END IF; 224 | 225 | -- sub nodes of an array node 226 | IF (n.par IS NOT NULL AND theNodes(n.par).typ = json_utils.NODE_TYPE_ARRAY AND n.nam IS NOT NULL) THEN 227 | error(i, 'Sub nodes of an array node are not allowed to have a property name'); 228 | END IF; 229 | 230 | -- type dependent validations 231 | CASE n.typ 232 | 233 | WHEN json_utils.NODE_TYPE_NULL THEN -- null 234 | IF (n.str IS NOT NULL OR n.num IS NOT NULL OR n.dat IS NOT NULL) THEN 235 | error(i, 'String or number value not NULL in a null node'); 236 | END IF; 237 | 238 | WHEN json_utils.NODE_TYPE_STRING THEN -- string 239 | IF (n.lob IS NOT NULL) THEN 240 | error(i, 'LOB value not NULL in a string node'); 241 | END IF; 242 | IF (n.num IS NOT NULL) THEN 243 | error(i, 'Number value not NULL in a string node'); 244 | END IF; 245 | IF (n.dat IS NOT NULL) THEN 246 | error(i, 'Date value not NULL in a string node'); 247 | END IF; 248 | 249 | WHEN json_utils.NODE_TYPE_LOB THEN -- lob 250 | IF (n.str IS NOT NULL) THEN 251 | error(i, 'String value not NULL in a string node'); 252 | END IF; 253 | IF (n.num IS NOT NULL) THEN 254 | error(i, 'Number value not NULL in a string node'); 255 | END IF; 256 | IF (n.dat IS NOT NULL) THEN 257 | error(i, 'Date value not NULL in a string node'); 258 | END IF; 259 | 260 | WHEN json_utils.NODE_TYPE_NUMBER THEN -- number 261 | IF (n.str IS NOT NULL) THEN 262 | error(i, 'String value not NULL in a number node'); 263 | END IF; 264 | IF (n.num IS NULL) THEN 265 | error(i, 'Number value is NULL in a number node'); 266 | END IF; 267 | IF (n.dat IS NOT NULL) THEN 268 | error(i, 'Date value not NULL in a number node'); 269 | END IF; 270 | 271 | WHEN json_utils.NODE_TYPE_DATE THEN -- date 272 | IF (n.str IS NOT NULL) THEN 273 | error(i, 'String value not NULL in a date node'); 274 | END IF; 275 | IF (n.num IS NOT NULL) THEN 276 | error(i, 'Number value is not NULL in a date node'); 277 | END IF; 278 | IF (n.dat IS NULL) THEN 279 | error(i, 'Date value is NULL in a date node'); 280 | END IF; 281 | 282 | WHEN json_utils.NODE_TYPE_BOOLEAN THEN -- boolean 283 | IF (n.str IS NOT NULL) THEN 284 | error(i, 'String value not NULL in a boolean node'); 285 | END IF; 286 | IF (n.num IS NULL OR n.num NOT IN (0, 1)) THEN 287 | error(i, 'Number values not 0 or 1 in a boolean node'); 288 | END IF; 289 | IF (n.dat IS NOT NULL) THEN 290 | error(i, 'Date value not NULL in a number node'); 291 | END IF; 292 | 293 | WHEN json_utils.NODE_TYPE_OBJECT THEN -- object 294 | /* 295 | an object node without subnotes defines an empty object 296 | 297 | IF (n.sub IS NULL OR NOT theNodes.EXISTS(n.sub)) THEN 298 | error(i, 'Object node with invalid "sub"'); 299 | END IF; 300 | */ 301 | NULL; 302 | 303 | WHEN json_utils.NODE_TYPE_ARRAY THEN -- array 304 | /* 305 | an array node without subnotes defines an empty array 306 | 307 | IF (n.sub IS NULL OR NOT theNodes.EXISTS(n.sub)) THEN 308 | error(i, 'Object node with invalid "sub"'); 309 | END IF; 310 | */ 311 | NULL; 312 | 313 | ELSE 314 | error(i, 'Invalid node type ('||n.typ||')'); 315 | 316 | END CASE; 317 | 318 | -- go to next node 319 | i := theNodes.NEXT(i); 320 | END LOOP; 321 | END validate; 322 | 323 | ---------------------------------------------------------- 324 | -- addNode 325 | -- 326 | FUNCTION addNode(theNodes IN OUT NOCOPY jsonNodes, theNode IN jsonNode) RETURN BINARY_INTEGER 327 | IS 328 | aCurrID BINARY_INTEGER; 329 | BEGIN 330 | -- add a new node 331 | theNodes.EXTEND(1); 332 | aCurrID := theNodes.LAST; 333 | theNodes(aCurrID) := theNode; 334 | 335 | RETURN aCurrID; 336 | END addNode; 337 | 338 | ---------------------------------------------------------- 339 | -- addNode 340 | -- 341 | FUNCTION addNode(theNodes IN OUT NOCOPY jsonNodes, theLastID IN OUT NOCOPY NUMBER, theNode IN jsonNode) RETURN BINARY_INTEGER 342 | IS 343 | aCurrID BINARY_INTEGER; 344 | BEGIN 345 | -- add a new node 346 | theNodes.EXTEND(1); 347 | aCurrID := theNodes.LAST; 348 | theNodes(aCurrID) := theNode; 349 | 350 | -- if we are a "main" node (a node that is actually a parameter in THIS object) 351 | IF (theNode.par IS NULL) THEN 352 | -- if we are not the first node, we must set the next argument in the currently last node 353 | IF (theLastID IS NOT NULL) THEN 354 | theNodes(theLastID).nex := aCurrID; 355 | END IF; 356 | 357 | -- set the last node 358 | theLastID := aCurrID; 359 | END IF; 360 | 361 | RETURN aCurrID; 362 | END addNode; 363 | 364 | ---------------------------------------------------------- 365 | -- copyNodes 366 | -- 367 | PROCEDURE copyNodes(theTargetNodes IN OUT NOCOPY jsonNodes, theTargetNodeID IN BINARY_INTEGER, theLastID IN OUT NOCOPY NUMBER, theName IN VARCHAR2, theSourceNodes IN jsonNodes) 368 | IS 369 | aLastID BINARY_INTEGER := theTargetNodes.LAST; 370 | aCurrID BINARY_INTEGER := NULL; 371 | aNode jsonNode := jsonNode(); 372 | aFirst BOOLEAN := TRUE; 373 | i BINARY_INTEGER; 374 | BEGIN 375 | i := theSourceNodes.FIRST; 376 | WHILE (i IS NOT NULL) LOOP 377 | -- get the node from source 378 | aNode := theSourceNodes(i); 379 | 380 | -- set the new id's relative to the current list of nodes 381 | aNode.sub := aNode.sub + aLastID; 382 | aNode.nex := aNode.nex + aLastID; 383 | 384 | -- set the parent node id 385 | IF (aNode.par IS NULL) THEN 386 | aNode.par := theTargetNodeID; 387 | ELSE 388 | aNode.par := aNode.par + aLastID; 389 | END IF; 390 | 391 | -- add the node 392 | aCurrID := json_utils.addNode(theNodes=>theTargetNodes, theLastID=>theLastID, theNode=>aNode); 393 | 394 | -- if this is the first sub-node, we must set the index to the sub notes in the parent 395 | IF (aFirst) THEN 396 | theTargetNodes(theTargetNodeID).sub := aCurrID; 397 | aFirst := FALSE; 398 | END IF; 399 | 400 | -- get the index to the next node 401 | i := theSourceNodes.NEXT(i); 402 | END LOOP; 403 | END copyNodes; 404 | 405 | ---------------------------------------------------------- 406 | -- createSubTree 407 | -- 408 | FUNCTION createSubTree(theSourceNodes IN jsonNodes, theSourceNodeID IN BINARY_INTEGER) RETURN jsonValue 409 | IS 410 | aData jsonValue := jsonValue(); 411 | aFirstID BINARY_INTEGER; 412 | BEGIN 413 | -- if we must only copy a basic node 414 | IF (theSourceNodes(theSourceNodeID).typ NOT IN (json_utils.NODE_TYPE_OBJECT, json_utils.NODE_TYPE_ARRAY)) THEN 415 | aData.nodes.EXTEND(1); 416 | aData.typ := NULL; 417 | aData.nodes(1) := theSourceNodes(theSourceNodeID); 418 | aData.nodes(1).par := NULL; 419 | aData.nodes(1).sub := NULL; 420 | aData.nodes(1).nex := NULL; 421 | RETURN aData; 422 | END IF; 423 | 424 | --dbms_output.put_line('json_util.createSubTree for object or array. starting with node: '||theSourceNodes(theSourceNodeID).sub); 425 | 426 | -- we must extract a subtree of nodes and create a new tree starting with the first node in the sub tree 427 | aData.typ := theSourceNodes(theSourceNodeID).typ; 428 | copySubNodes(theTarget=>aData.nodes, theFirstID=>aFirstID, theParentID=>NULL, theSource=>theSourceNodes, theFirstSourceID=>theSourceNodes(theSourceNodeID).sub); 429 | 430 | RETURN aData; 431 | END createSubTree; 432 | 433 | ---------------------------------------------------------- 434 | -- removeNode 435 | -- 436 | FUNCTION removeNode(theNodes IN OUT NOCOPY jsonNodes, theNodeID IN BINARY_INTEGER) RETURN BINARY_INTEGER 437 | IS 438 | aNodes CONSTANT jsonNodes := theNodes; 439 | aNode jsonNode; 440 | aOldNodeCount BINARY_INTEGER; 441 | aNewNodeCount BINARY_INTEGER; 442 | aFound BOOLEAN := FALSE; 443 | aCurrID BINARY_INTEGER; 444 | aFirstID BINARY_INTEGER; 445 | aLastID BINARY_INTEGER; 446 | aSourceNodeID BINARY_INTEGER; 447 | BEGIN 448 | -- 449 | -- It is only possible to remove a node by basically creating a completely new tree and this is done by first copying 450 | -- the original tree and then trsversing the copy and create a new tree without the remove node and all it's possible 451 | -- sub-trees. 452 | -- 453 | 454 | --json_debug.output(theNodes=>theNodes, theRawFlag=>TRUE, theTitle=>'before removeNode'); 455 | 456 | -- make sure that we have the node to remove on the root level and save the number of nodes in the root level 457 | aSourceNodeID := theNodes.FIRST; 458 | aOldNodeCount := 0; 459 | WHILE (aSourceNodeID IS NOT NULL) LOOP 460 | aOldNodeCount := aOldNodeCount + 1; 461 | IF (aSourceNodeID = theNodeID) THEN 462 | aFound := TRUE; 463 | END IF; 464 | aSourceNodeID := theNodes(aSourceNodeID).nex; 465 | END LOOP; 466 | IF (NOT aFound) THEN 467 | raise_application_error(-20100, 'Cannot find node: '||theNodeID, TRUE); 468 | END IF; 469 | 470 | -- delete all original nodes 471 | IF (aNodes.COUNT != theNodes.COUNT) THEN 472 | raise_application_error(-20100, 'Not all node have been copied', TRUE); 473 | END IF; 474 | theNodes.DELETE; 475 | IF (theNodes.COUNT != 0) THEN 476 | raise_application_error(-20100, 'Not all nodes have been removed', TRUE); 477 | END IF; 478 | 479 | -- process the nodes on the root level (the ones that have no parent and use the next link) 480 | aSourceNodeID := aNodes.FIRST; 481 | WHILE (aSourceNodeID IS NOT NULL) LOOP 482 | -- get the source node 483 | aNode := aNodes(aSourceNodeID); 484 | 485 | -- reset the nex "attribute" because it might get removed 486 | aNode.nex := NULL; 487 | 488 | -- make sure that all nodes on the root level of an object or array have no parent 489 | IF (aNode.par IS NOT NULL) THEN 490 | raise_application_error(-20100, 'Invalid par attribute in node: '||aSourceNodeID, TRUE); 491 | END IF; 492 | 493 | -- this node needs to be copied 494 | IF (aSourceNodeID != theNodeID) THEN 495 | -- add the node 496 | aCurrID := addNode(theNodes=>theNodes, theLastID=>aLastID, theNode=>aNode); 497 | 498 | -- if there are any sub-notes, we must copy them recursively 499 | IF (aNode.typ IN (json_utils.NODE_TYPE_OBJECT, json_utils.NODE_TYPE_ARRAY)) THEN 500 | IF (aNode.sub IS NULL) THEN 501 | raise_application_error(-20100, 'Invalid sub attribute in node: '||aSourceNodeID, TRUE); 502 | END IF; 503 | 504 | -- copy the sub notes 505 | aFirstID := NULL; 506 | copySubNodes(theTarget=>theNodes, theFirstID=>aFirstID, theParentID=>aCurrID, theSource=>aNodes, theFirstSourceID=>aNode.sub); 507 | 508 | -- set the new sub id in the node 509 | theNodes(aCurrID).sub := aFirstID; 510 | END IF; 511 | END IF; 512 | 513 | aSourceNodeID := aNodes(aSourceNodeID).nex; 514 | END LOOP; 515 | 516 | -- make sure that we have removed exactly one node in the root level 517 | aSourceNodeID := theNodes.FIRST; 518 | aNewNodeCount := 0; 519 | WHILE (aSourceNodeID IS NOT NULL) LOOP 520 | aNewNodeCount := aNewNodeCount + 1; 521 | aSourceNodeID := theNodes(aSourceNodeID).nex; 522 | END LOOP; 523 | IF (aNewNodeCount != aOldNodeCount - 1) THEN 524 | raise_application_error(-20100, 'Invalid number of nodes after removing one. before: '||aOldNodeCount||' after: '||aNewNodeCount, TRUE); 525 | END IF; 526 | 527 | --json_debug.output(theNodes=>theNodes, theRawFlag=>TRUE, theTitle=>'after removeNode'); 528 | 529 | RETURN aLastID; 530 | END removeNode; 531 | 532 | ---------------------------------------------------------- 533 | -- value_to_clob 534 | -- 535 | PROCEDURE value_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER) 536 | IS 537 | PRAGMA INLINE (get_gap, 'YES'); 538 | GAP CONSTANT VARCHAR2(32767) := get_gap(theIndentation); 539 | 540 | aNode jsonNode := theNodes(theNodeID); 541 | aName VARCHAR2(32767); 542 | aCLOB CLOB; 543 | BEGIN 544 | -- Add the property name 545 | IF (aNode.nam IS NOT NULL) THEN 546 | PRAGMA INLINE (escape, 'YES'); 547 | aName := GAP || '"' || escape(theString=>aNode.nam, theAsciiOutput=>outputOptions.ascii_output, theEscapeSolitus=>outputOptions.escape_solitus) || '":'; 548 | IF (outputOptions.Pretty) THEN 549 | aName := aName || ' '; 550 | END IF; 551 | 552 | PRAGMA INLINE (add_string, 'YES'); 553 | json_utils.add_string(theLobBuf, theStrBuf, aName); 554 | ELSE 555 | PRAGMA INLINE (add_string, 'YES'); 556 | json_utils.add_string(theLobBuf, theStrBuf, GAP); 557 | END IF; 558 | 559 | -- Add the property value 560 | CASE aNode.typ 561 | 562 | WHEN json_utils.NODE_TYPE_NULL THEN 563 | PRAGMA INLINE (add_string, 'YES'); 564 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>'null'); 565 | 566 | WHEN json_utils.NODE_TYPE_STRING THEN 567 | PRAGMA INLINE (escape, 'YES'); 568 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>'"' || escape(theString=>aNode.str, theAsciiOutput=>outputOptions.ascii_output, theEscapeSolitus=>outputOptions.escape_solitus) || '"'); 569 | 570 | WHEN json_utils.NODE_TYPE_LOB THEN 571 | PRAGMA INLINE (add_string, 'YES'); 572 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>'"'); 573 | PRAGMA INLINE (escapeLOB, 'YES'); 574 | escapeLOB(theInputLob=>aNode.lob, theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theAsciiOutput=>outputOptions.ascii_output, theEscapeSolitus=>outputOptions.escape_solitus); 575 | PRAGMA INLINE (add_string, 'YES'); 576 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>'"'); 577 | 578 | WHEN json_utils.NODE_TYPE_NUMBER THEN 579 | PRAGMA INLINE (number_to_json, 'YES'); 580 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>number_to_json(aNode.num)); 581 | 582 | WHEN json_utils.NODE_TYPE_DATE THEN 583 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>'"' || TO_CHAR(aNode.dat, 'FXYYYY-MM-DD"T"HH24:MI:SS') || '"'); 584 | 585 | WHEN json_utils.NODE_TYPE_BOOLEAN THEN 586 | PRAGMA INLINE (boolean_to_json, 'YES'); 587 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>boolean_to_json(aNode.num)); 588 | 589 | WHEN json_utils.NODE_TYPE_OBJECT THEN 590 | json_utils.object_to_clob(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theNodes=>theNodes, theNodeID=>theNodes(theNodeID).sub, theIndentation=>theIndentation, theFlushToLOB=>FALSE); 591 | 592 | WHEN json_utils.NODE_TYPE_ARRAY THEN 593 | json_utils.array_to_clob(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theNodes=>theNodes, theNodeID=>theNodes(theNodeID).sub, theIndentation=>theIndentation, theFlushToLOB=>FALSE); 594 | 595 | ELSE 596 | raise_application_error(-20100, 'Invalid node type: '||aNode.typ, TRUE); 597 | END CASE; 598 | END value_to_clob; 599 | 600 | ---------------------------------------------------------- 601 | -- object_to_clob 602 | -- 603 | PROCEDURE object_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER, theFlushToLOB IN BOOLEAN DEFAULT TRUE) 604 | IS 605 | PRAGMA INLINE (get_gap, 'YES'); 606 | GAP CONSTANT VARCHAR2(32767) := get_gap(theIndentation); 607 | 608 | aBracket VARCHAR2(32767); 609 | aDelimiter VARCHAR2(32767); 610 | aNodeID BINARY_INTEGER := theNodeID; 611 | BEGIN 612 | -- open bracket { 613 | IF (outputOptions.Pretty) THEN 614 | aBracket := '{' || outputOptions.newline_char; 615 | ELSE 616 | aBracket := '{'; 617 | END IF; 618 | PRAGMA INLINE (add_string, 'YES'); 619 | json_utils.add_string(theLobBuf, theStrBuf, aBracket); 620 | 621 | -- compute the delimiter 622 | IF (outputOptions.Pretty) THEN 623 | aDelimiter := ',' || outputOptions.newline_char; 624 | ELSE 625 | aDelimiter := ','; 626 | END IF; 627 | 628 | -- process all properties in the object 629 | WHILE (aNodeID IS NOT NULL) LOOP 630 | -- Add separator from last property if we are not the first one 631 | IF (aNodeID != theNodeID) THEN 632 | PRAGMA INLINE (add_string, 'YES'); 633 | json_utils.add_string(theLobBuf, theStrBuf, aDelimiter); 634 | END IF; 635 | 636 | -- Add the property pair 637 | theIndentation := theIndentation + 1; 638 | --PRAGMA INLINE (value_to_clob, 'YES'); 639 | json_utils.value_to_clob(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theNodes=>theNodes, theNodeID=>aNodeID, theIndentation=>theIndentation); 640 | theIndentation := theIndentation -+ 1; 641 | 642 | aNodeID := theNodes(aNodeID).nex; 643 | END LOOP; 644 | 645 | -- close bracket } 646 | IF (outputOptions.Pretty) THEN 647 | aBracket := outputOptions.newline_char || GAP || '}'; 648 | ELSE 649 | aBracket := GAP || '}'; 650 | END IF; 651 | PRAGMA INLINE (add_string, 'YES'); 652 | json_utils.add_string(theLobBuf, theStrBuf, aBracket); 653 | 654 | -- flush 655 | IF (theFlushToLOB) THEN 656 | json_utils.flush_clob(theLobBuf, theStrBuf); 657 | END IF; 658 | END object_to_clob; 659 | 660 | ---------------------------------------------------------- 661 | -- array_to_clob 662 | -- 663 | PROCEDURE array_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER, theFlushToLOB IN BOOLEAN DEFAULT TRUE) 664 | IS 665 | PRAGMA INLINE (get_gap, 'YES'); 666 | GAP CONSTANT VARCHAR2(32767) := get_gap(theIndentation); 667 | 668 | aBracket VARCHAR2(32767); 669 | aDelimiter VARCHAR2(32767); 670 | aNodeID BINARY_INTEGER := theNodeID; 671 | BEGIN 672 | -- open bracket { 673 | IF (outputOptions.Pretty) THEN 674 | aBracket := '[' || outputOptions.newline_char; 675 | ELSE 676 | aBracket := '['; 677 | END IF; 678 | PRAGMA INLINE (add_string, 'YES'); 679 | json_utils.add_string(theLobBuf, theStrBuf, aBracket); 680 | 681 | -- compute the delimiter 682 | IF (outputOptions.Pretty) THEN 683 | aDelimiter := ',' || outputOptions.newline_char; 684 | ELSE 685 | aDelimiter := ','; 686 | END IF; 687 | 688 | -- process all properties in the object 689 | WHILE (aNodeID IS NOT NULL) LOOP 690 | -- Add separator from last array entry if we are not the first one 691 | IF (aNodeID != theNodeID) THEN 692 | PRAGMA INLINE (add_string, 'YES'); 693 | json_utils.add_string(theLobBuf, theStrBuf, aDelimiter); 694 | END IF; 695 | 696 | -- Add the property pair 697 | theIndentation := theIndentation + 1; 698 | PRAGMA INLINE (value_to_clob, 'YES'); 699 | json_utils.value_to_clob(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theNodes=>theNodes, theNodeID=>aNodeID, theIndentation=>theIndentation); 700 | theIndentation := theIndentation - 1; 701 | 702 | aNodeID := theNodes(aNodeID).nex; 703 | END LOOP; 704 | 705 | -- close bracket } 706 | IF (outputOptions.Pretty) THEN 707 | aBracket := outputOptions.newline_char || GAP || ']'; 708 | ELSE 709 | aBracket := GAP || ']'; 710 | END IF; 711 | PRAGMA INLINE (add_string, 'YES'); 712 | json_utils.add_string(theLobBuf, theStrBuf, aBracket); 713 | 714 | -- flush 715 | IF (theFlushToLOB) THEN 716 | json_utils.flush_clob(theLobBuf, theStrBuf); 717 | END IF; 718 | END array_to_clob; 719 | 720 | ---------------------------------------------------------- 721 | -- htp_output_clob 722 | -- 723 | PROCEDURE htp_output_clob(theLobBuf IN CLOB, theJSONP IN VARCHAR2 DEFAULT NULL) 724 | IS 725 | amt NUMBER := 30; 726 | off NUMBER := 1; 727 | str VARCHAR2(4096); 728 | BEGIN 729 | htp_output_open(theJSONP=>theJSONP); 730 | 731 | BEGIN 732 | LOOP 733 | dbms_lob.read(theLobBuf, amt, off, str); 734 | htp.prn(str); 735 | off := off + amt; 736 | amt := 4096; 737 | END LOOP; 738 | EXCEPTION 739 | WHEN no_data_found THEN 740 | NULL; 741 | END; 742 | 743 | htp_output_close(theJSONP=>theJSONP); 744 | END htp_output_clob; 745 | 746 | ---------------------------------------------------------- 747 | -- htp_output_open 748 | -- 749 | PROCEDURE htp_output_open(theJSONP IN VARCHAR2 DEFAULT NULL) 750 | IS 751 | MIME_TYPE CONSTANT VARCHAR2(30) := 'application/json'; 752 | NO_CACHE CONSTANT VARCHAR2(32767) := 'Cache-Control: no-store, no-cache, must-revalidate, max-age=0 753 | Cache-Control: post-check=0, pre-check=0 754 | Pragma: no-cache 755 | Expires: -1'; 756 | BEGIN 757 | -- generate the http header identifying this as json and prevent browsers (IE is very agressive here) from caching 758 | owa_util.mime_header(MIME_TYPE, FALSE); 759 | htp.p(NO_CACHE); 760 | owa_util.http_header_close; 761 | 762 | -- the JSONP callback 763 | IF (theJSONP IS NOT NULL) THEN 764 | htp.prn(theJSONP || '('); 765 | END IF; 766 | END htp_output_open; 767 | 768 | ---------------------------------------------------------- 769 | -- htp_output_close 770 | -- 771 | PROCEDURE htp_output_close(theJSONP IN VARCHAR2 DEFAULT NULL) 772 | IS 773 | BEGIN 774 | -- the JSONP callback 775 | IF (theJSONP IS NOT NULL) THEN 776 | htp.prn(')'); 777 | END IF; 778 | END htp_output_close; 779 | 780 | ---------------------------------------------------------- 781 | -- get_gap (private) 782 | -- 783 | FUNCTION get_gap(theIndentation IN INTEGER) RETURN VARCHAR2 784 | IS 785 | BEGIN 786 | IF (outputOptions.Pretty) THEN 787 | RETURN RPAD(outputOptions.indentation_char, theIndentation, outputOptions.indentation_char); 788 | ELSE 789 | RETURN ''; 790 | END IF; 791 | END get_gap; 792 | 793 | ---------------------------------------------------------- 794 | -- copySubNodes (private) 795 | -- 796 | PROCEDURE copySubNodes(theTarget IN OUT NOCOPY jsonNodes, theFirstID IN OUT NOCOPY BINARY_INTEGER, theParentID IN BINARY_INTEGER, theSource IN jsonNodes, theFirstSourceID IN BINARY_INTEGER) 797 | IS 798 | aLastID BINARY_INTEGER; 799 | aCurrID BINARY_INTEGER; 800 | aSourceID BINARY_INTEGER := theFirstSourceID; 801 | BEGIN 802 | WHILE (aSourceID IS NOT NULL) LOOP 803 | -- add a new node 804 | theTarget.EXTEND(1); 805 | aCurrID := theTarget.LAST; 806 | theTarget(aCurrID) := theSource(aSourceID); 807 | theTarget(aCurrID).par := theParentID; 808 | theTarget(aCurrID).nex := NULL; 809 | theTarget(aCurrID).sub := CASE theSource(aSourceID).sub IS NOT NULL WHEN TRUE THEN aCurrID + 1 ELSE NULL END; 810 | 811 | -- save the first id 812 | IF (aSourceID = theFirstSourceID AND theFirstID IS NULL) THEN 813 | theFirstID := aCurrID; 814 | END IF; 815 | 816 | -- set the next id 817 | IF (aLastID IS NOT NULL) THEN 818 | theTarget(aLastID).nex := aCurrID; 819 | END IF; 820 | aLastID := aCurrID; 821 | 822 | -- if the node has subnodes recurse into the subnodes 823 | IF (theSource(aSourceID).sub IS NOT NULL) THEN 824 | copySubNodes(theTarget=>theTarget, theFirstID=>theFirstID, theParentID=>aCurrID, theSource=>theSource, theFirstSourceID=>theSource(aSourceID).sub); 825 | END IF; 826 | 827 | -- go to the next node 828 | aSourceID := theSource(aSourceID).nex; 829 | END LOOP; 830 | END copySubNodes; 831 | 832 | ---------------------------------------------------------- 833 | -- number_to_json (private) 834 | -- 835 | FUNCTION number_to_json(theNumber IN NUMBER) RETURN VARCHAR2 836 | IS 837 | s VARCHAR2(32767); 838 | BEGIN 839 | IF (theNumber IS NOT NULL) THEN 840 | IF (theNumber < 1 AND theNumber > 0) THEN 841 | s := '0'|| TO_CHAR(theNumber, 'TM9', 'NLS_NUMERIC_CHARACTERS=''.,'''); 842 | ELSIF (theNumber < 0 AND theNumber > -1) THEN 843 | s := '-0' || SUBSTR(TO_CHAR(theNumber, 'TM9', 'NLS_NUMERIC_CHARACTERS=''.,'''), 2); 844 | ELSE 845 | s := TO_CHAR(theNumber, 'TM9', 'NLS_NUMERIC_CHARACTERS=''.,'''); 846 | END IF; 847 | ELSE 848 | s := 'null'; 849 | END IF; 850 | 851 | RETURN s; 852 | END number_to_json; 853 | 854 | ---------------------------------------------------------- 855 | -- boolean_to_json (private) 856 | -- 857 | FUNCTION boolean_to_json(theBoolean IN NUMBER) RETURN VARCHAR2 858 | IS 859 | s VARCHAR2(32767); 860 | BEGIN 861 | IF (theBoolean IS NOT NULL) THEN 862 | s := CASE theBoolean WHEN 1 THEN 'true' ELSE 'false' END; 863 | ELSE 864 | s := 'null'; 865 | END IF; 866 | 867 | RETURN s; 868 | END boolean_to_json; 869 | 870 | ---------------------------------------------------------- 871 | -- escape 872 | -- 873 | FUNCTION escape(theString IN VARCHAR2, theAsciiOutput IN BOOLEAN DEFAULT TRUE, theEscapeSolitus IN BOOLEAN DEFAULT FALSE) RETURN VARCHAR2 874 | IS 875 | sb VARCHAR2(32767) := ''; 876 | buf VARCHAR2(64); 877 | num NUMBER; 878 | BEGIN 879 | IF (theString IS NULL) THEN 880 | RETURN ''; 881 | END IF; 882 | 883 | FOR I IN 1 .. LENGTH(theString) LOOP 884 | buf := SUBSTR(theString, i, 1); 885 | 886 | CASE buf 887 | WHEN CHR(8) THEN buf := '\b'; -- backspace b = U+0008 = chr(8) 888 | WHEN CHR(9) THEN buf := '\t'; -- tabulator t = U+0009 = chr(9) 889 | WHEN CHR(10) THEN buf := '\n'; -- newline n = U+000A = chr(10) 890 | WHEN CHR(12) THEN buf := '\f'; -- formfeed f = U+000C = chr(12) 891 | WHEN CHR(13) THEN buf := '\r'; -- carret r = U+000D = chr(13) 892 | WHEN CHR(34) THEN buf := '\"'; 893 | WHEN CHR(47) THEN -- slash 894 | IF (theEscapeSolitus) THEN 895 | buf := '\/'; 896 | END IF; 897 | WHEN CHR(92) THEN buf := '\\'; -- backslash 898 | ELSE 899 | IF (ASCII(buf) < 32) THEN 900 | buf := '\u' || REPLACE(SUBSTR(TO_CHAR(ASCII(buf), 'XXXX'), 2, 4), ' ', '0'); 901 | ELSIF (theAsciiOutput) then 902 | buf := REPLACE(ASCIISTR(buf), '\', '\u'); 903 | END IF; 904 | END CASE; 905 | 906 | sb := sb || buf; 907 | END LOOP; 908 | 909 | RETURN sb; 910 | END escape; 911 | 912 | ---------------------------------------------------------- 913 | -- escapeLOB (private) 914 | -- 915 | PROCEDURE escapeLOB(theInputLob IN CLOB, theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theAsciiOutput IN BOOLEAN DEFAULT TRUE, theEscapeSolitus IN BOOLEAN DEFAULT FALSE) 916 | IS 917 | len CONSTANT NUMBER := dbms_lob.getlength(lob_loc=>theInputLob); 918 | str VARCHAR2(32767); 919 | buf VARCHAR2(64); 920 | num NUMBER; 921 | BEGIN 922 | -- empty CLOB 923 | IF (theInputLob IS NULL OR len = 0) THEN 924 | RETURN; 925 | END IF; 926 | 927 | -- is the CLOB is so short (32767 / 6) that we can convert it like a VARCHAR2 928 | IF (len <= 4000) THEN 929 | str := escape(theString=>theInputLob, theAsciiOutput=>theAsciiOutput, theEscapeSolitus=>theEscapeSolitus); 930 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>str); 931 | RETURN; 932 | END IF; 933 | 934 | -- is the CLOB short enough that we can at leat select from it like a VARCHAR2 935 | IF (len <= 32767) THEN 936 | str := theInputLob; 937 | END IF; 938 | 939 | -- process the lob 940 | FOR I IN 1 .. len LOOP 941 | IF (str IS NOT NULL) THEN 942 | buf := SUBSTR(str, i, 1); 943 | ELSE 944 | buf := dbms_lob.substr(lob_loc=>theInputLob, amount=>1, offset=>i); 945 | END IF; 946 | 947 | CASE buf 948 | WHEN CHR(8) THEN buf := '\b'; -- backspace b = U+0008 = chr(8) 949 | WHEN CHR(9) THEN buf := '\t'; -- tabulator t = U+0009 = chr(9) 950 | WHEN CHR(10) THEN buf := '\n'; -- newline n = U+000A = chr(10) 951 | WHEN CHR(12) THEN buf := '\f'; -- formfeed f = U+000C = chr(12) 952 | WHEN CHR(13) THEN buf := '\r'; -- carret r = U+000D = chr(13) 953 | WHEN CHR(34) THEN buf := '\"'; 954 | WHEN CHR(47) THEN -- slash 955 | IF (theEscapeSolitus) THEN 956 | buf := '\/'; 957 | END IF; 958 | WHEN CHR(92) THEN buf := '\\'; -- backslash 959 | ELSE 960 | IF (ASCII(buf) < 32) THEN 961 | buf := '\u' || REPLACE(SUBSTR(TO_CHAR(ASCII(buf), 'XXXX'), 2, 4), ' ', '0'); 962 | ELSIF (theAsciiOutput) then 963 | buf := REPLACE(ASCIISTR(buf), '\', '\u'); 964 | END IF; 965 | END CASE; 966 | 967 | PRAGMA INLINE (add_string, 'YES'); 968 | json_utils.add_string(theLobBuf=>theLobBuf, theStrBuf=>theStrBuf, theValue=>buf); 969 | END LOOP; 970 | END escapeLOB; 971 | 972 | END json_utils; 973 | / 974 | -------------------------------------------------------------------------------- /json_utils.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_utils 3 | IS 4 | 5 | -- indentation styles 6 | IND_TAB CONSTANT VARCHAR2(1 CHAR) := CHR(9); 7 | IND_SPACE_1 CONSTANT VARCHAR2(1 CHAR) := ' '; 8 | IND_SPACE_2 CONSTANT VARCHAR2(2 CHAR) := ' '; 9 | IND_SPACE_3 CONSTANT VARCHAR2(3 CHAR) := ' '; 10 | IND_SPACE_4 CONSTANT VARCHAR2(4 CHAR) := ' '; 11 | 12 | -- end of line styles 13 | EOL_LF CONSTANT VARCHAR2(1 CHAR) := CHR(10); -- macos 14 | EOL_CR CONSTANT VARCHAR2(1 CHAR) := CHR(13); -- linux 15 | EOL_CRLF CONSTANT VARCHAR2(2 CHAR) := EOL_CR || EOL_LF; -- windows 16 | 17 | -- output options 18 | TYPE outputOptionsType IS RECORD 19 | ( 20 | pretty BOOLEAN DEFAULT FALSE, 21 | newline_char VARCHAR2(2 CHAR) DEFAULT EOL_CRLF, 22 | indentation_char VARCHAR2(4 CHAR) DEFAULT IND_TAB, 23 | ascii_output BOOLEAN DEFAULT TRUE, 24 | escape_solitus BOOLEAN DEFAULT FALSE 25 | ); 26 | 27 | -- node types 28 | NODE_TYPE_NULL CONSTANT VARCHAR2(1 CHAR) := '0'; 29 | NODE_TYPE_STRING CONSTANT VARCHAR2(1 CHAR) := 'S'; 30 | NODE_TYPE_LOB CONSTANT VARCHAR2(1 CHAR) := 'L'; 31 | NODE_TYPE_NUMBER CONSTANT VARCHAR2(1 CHAR) := 'N'; 32 | NODE_TYPE_DATE CONSTANT VARCHAR2(1 CHAR) := 'D'; 33 | NODE_TYPE_BOOLEAN CONSTANT VARCHAR2(1 CHAR) := 'B'; 34 | NODE_TYPE_OBJECT CONSTANT VARCHAR2(1 CHAR) := 'O'; 35 | NODE_TYPE_ARRAY CONSTANT VARCHAR2(1 CHAR) := 'A'; 36 | 37 | ---------------------------------------------------------- 38 | -- get_default_options 39 | -- 40 | FUNCTION get_default_options RETURN outputOptionsType; 41 | 42 | ---------------------------------------------------------- 43 | -- get_options 44 | -- 45 | FUNCTION get_options RETURN outputOptionsType; 46 | 47 | ---------------------------------------------------------- 48 | -- set_options 49 | -- 50 | PROCEDURE set_options(theOptions IN outputOptionsType); 51 | 52 | ---------------------------------------------------------- 53 | -- add_string 54 | -- 55 | PROCEDURE add_string(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theValue IN VARCHAR2); 56 | 57 | ---------------------------------------------------------- 58 | -- add_clob 59 | -- 60 | PROCEDURE add_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theValue IN CLOB); 61 | 62 | ---------------------------------------------------------- 63 | -- erase_clob 64 | -- 65 | PROCEDURE erase_clob(theLobBuf IN OUT NOCOPY CLOB); 66 | 67 | ---------------------------------------------------------- 68 | -- flush_clob 69 | -- 70 | PROCEDURE flush_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2); 71 | 72 | ---------------------------------------------------------- 73 | -- get the number of nodes 74 | -- 75 | FUNCTION getNodeCount(theNodes IN jsonNodes) RETURN BINARY_INTEGER; 76 | 77 | ---------------------------------------------------------- 78 | -- get the node id for the given property name 79 | -- 80 | FUNCTION getNodeIDByName(theNodes IN jsonNodes, thePropertyName IN VARCHAR2) RETURN BINARY_INTEGER; 81 | 82 | ---------------------------------------------------------- 83 | -- get the node id for the given property 1-relative index 84 | -- 85 | FUNCTION getNodeIDByIndex(theNodes IN jsonNodes, thePropertyIndex IN NUMBER) RETURN BINARY_INTEGER; 86 | 87 | ---------------------------------------------------------- 88 | -- validate the given list of nodes and raise an 89 | -- exception with id -20100, if an inconsistency is found 90 | -- 91 | PROCEDURE validate(theNodes IN OUT NOCOPY jsonNodes); 92 | 93 | ---------------------------------------------------------- 94 | -- add a new node to the list of nodes 95 | -- 96 | FUNCTION addNode(theNodes IN OUT NOCOPY jsonNodes, theNode IN jsonNode) RETURN BINARY_INTEGER; 97 | 98 | ---------------------------------------------------------- 99 | -- add a new node to the list of nodes and update the 100 | -- next id pointer in the previous node 101 | -- 102 | FUNCTION addNode(theNodes IN OUT NOCOPY jsonNodes, theLastID IN OUT NOCOPY NUMBER, theNode IN jsonNode) RETURN BINARY_INTEGER; 103 | 104 | ---------------------------------------------------------- 105 | -- copy nodes to a new target node 106 | -- 107 | PROCEDURE copyNodes(theTargetNodes IN OUT NOCOPY jsonNodes, theTargetNodeID IN BINARY_INTEGER, theLastID IN OUT NOCOPY NUMBER, theName IN VARCHAR2, theSourceNodes IN jsonNodes); 108 | 109 | ---------------------------------------------------------- 110 | -- create subtree of nodes 111 | -- 112 | FUNCTION createSubTree(theSourceNodes IN jsonNodes, theSourceNodeID IN BINARY_INTEGER) RETURN jsonValue; 113 | 114 | ---------------------------------------------------------- 115 | -- remove the given node and all of it's subnodes 116 | -- 117 | FUNCTION removeNode(theNodes IN OUT NOCOPY jsonNodes, theNodeID IN BINARY_INTEGER) RETURN BINARY_INTEGER; 118 | 119 | ---------------------------------------------------------- 120 | -- convert a node value to a JSON string 121 | -- 122 | PROCEDURE value_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER); 123 | 124 | ---------------------------------------------------------- 125 | -- convert an object to a JSON string 126 | -- 127 | PROCEDURE object_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER, theFlushToLOB IN BOOLEAN DEFAULT TRUE); 128 | 129 | ---------------------------------------------------------- 130 | -- convert an array to a JSON string 131 | -- 132 | PROCEDURE array_to_clob(theLobBuf IN OUT NOCOPY CLOB, theStrBuf IN OUT NOCOPY VARCHAR2, theNodes IN jsonNodes, theNodeID IN NUMBER, theIndentation IN OUT INTEGER, theFlushToLOB IN BOOLEAN DEFAULT TRUE); 133 | 134 | ---------------------------------------------------------- 135 | -- copy output to the browser using htp.prn 136 | -- 137 | PROCEDURE htp_output_clob(theLobBuf IN CLOB, theJSONP IN VARCHAR2 DEFAULT NULL); 138 | 139 | ---------------------------------------------------------- 140 | -- open the output to the browser 141 | -- 142 | PROCEDURE htp_output_open(theJSONP IN VARCHAR2 DEFAULT NULL); 143 | 144 | ---------------------------------------------------------- 145 | -- close the output to the browser 146 | -- 147 | PROCEDURE htp_output_close(theJSONP IN VARCHAR2 DEFAULT NULL); 148 | 149 | ---------------------------------------------------------- 150 | -- escape 151 | -- 152 | FUNCTION escape(theString IN VARCHAR2, theAsciiOutput IN BOOLEAN DEFAULT TRUE, theEscapeSolitus IN BOOLEAN DEFAULT FALSE) RETURN VARCHAR2; 153 | 154 | END json_utils; 155 | / 156 | -------------------------------------------------------------------------------- /jsonarray.tpb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE BODY jsonArray IS 3 | 4 | ---------------------------------------------------------- 5 | -- jsonArray 6 | -- 7 | CONSTRUCTOR FUNCTION jsonArray(SELF IN OUT NOCOPY jsonArray) RETURN SELF AS result 8 | IS 9 | BEGIN 10 | nodes := jsonNodes(); 11 | lastID := NULL; 12 | RETURN; 13 | END jsonArray; 14 | 15 | ---------------------------------------------------------- 16 | -- jsonArray 17 | -- 18 | CONSTRUCTOR FUNCTION jsonArray(SELF IN OUT NOCOPY jsonArray, theData IN jsonValue) RETURN SELF AS result 19 | IS 20 | BEGIN 21 | IF (theData.typ != json_utils.NODE_TYPE_ARRAY) THEN 22 | raise_application_error(-20100, 'jsonArray exception: unable to convert node ('||theData.typ||') to an array'); 23 | ELSE 24 | SELF.nodes := theData.nodes; 25 | SELF.lastID := NULL; 26 | END IF; 27 | RETURN; 28 | END jsonArray; 29 | 30 | ---------------------------------------------------------- 31 | -- append 32 | -- 33 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray) 34 | IS 35 | aNodeID BINARY_INTEGER; 36 | BEGIN 37 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL)); 38 | END append; 39 | 40 | ---------------------------------------------------------- 41 | -- append (VARCHAR2) 42 | -- 43 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN VARCHAR2) 44 | IS 45 | aNodeID BINARY_INTEGER; 46 | BEGIN 47 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL, theValue)); 48 | END append; 49 | 50 | ---------------------------------------------------------- 51 | -- append (CLOB) 52 | -- 53 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN CLOB) 54 | IS 55 | aNodeID BINARY_INTEGER; 56 | BEGIN 57 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL, theValue)); 58 | END append; 59 | 60 | ---------------------------------------------------------- 61 | -- append (NUMBER) 62 | -- 63 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN NUMBER) 64 | IS 65 | aNodeID BINARY_INTEGER; 66 | BEGIN 67 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL, theValue)); 68 | END append; 69 | 70 | ---------------------------------------------------------- 71 | -- append (DATE) 72 | -- 73 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN DATE) 74 | IS 75 | aNodeID BINARY_INTEGER; 76 | BEGIN 77 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL, theValue)); 78 | END append; 79 | 80 | ---------------------------------------------------------- 81 | -- append (BOOLEAN) 82 | -- 83 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN BOOLEAN) 84 | IS 85 | aNodeID BINARY_INTEGER; 86 | BEGIN 87 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(NULL, theValue)); 88 | END append; 89 | 90 | ---------------------------------------------------------- 91 | -- append 92 | -- 93 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN jsonObject) 94 | IS 95 | aNodeID BINARY_INTEGER; 96 | BEGIN 97 | -- add a new object node that will be used as the root for all the sub notes 98 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(json_utils.NODE_TYPE_OBJECT, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL)); 99 | 100 | -- copy the sub-nodes 101 | json_utils.copyNodes(theTargetNodes=>SELF.nodes, theTargetNodeID=>aNodeID, theLastID=>SELF.lastID, theName=>NULL, theSourceNodes=>theValue.nodes); 102 | END append; 103 | 104 | ---------------------------------------------------------- 105 | -- append 106 | -- 107 | MEMBER PROCEDURE append(SELF IN OUT NOCOPY jsonArray, theValue IN jsonArray) 108 | IS 109 | aNodeID BINARY_INTEGER; 110 | BEGIN 111 | -- add a new array node that will be used as the root for all the sub notes 112 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(json_utils.NODE_TYPE_ARRAY, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL)); 113 | 114 | -- copy the sub-nodes 115 | json_utils.copyNodes(theTargetNodes=>SELF.nodes, theTargetNodeID=>aNodeID, theLastID=>SELF.lastID, theName=>NULL, theSourceNodes=>theValue.nodes); 116 | END append; 117 | 118 | ---------------------------------------------------------- 119 | -- count 120 | -- 121 | MEMBER FUNCTION count(SELF IN jsonArray) RETURN NUMBER 122 | IS 123 | BEGIN 124 | RETURN json_utils.getNodeCount(SELF.nodes); 125 | END count; 126 | 127 | ---------------------------------------------------------- 128 | -- get 129 | -- 130 | MEMBER FUNCTION get(SELF IN jsonArray, thePropertyIndex IN NUMBER) RETURN jsonValue 131 | IS 132 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByIndex(theNodes=>SELF.nodes, thePropertyIndex=>thePropertyIndex); 133 | BEGIN 134 | IF (aNodeID IS NOT NULL) THEN 135 | RETURN json_utils.createSubTree(theSourceNodes=>SELF.nodes, theSourceNodeID=>aNodeID); 136 | ELSE 137 | raise_application_error(-20100, 'jsonObject exception: property ('||thePropertyIndex||') does not exit'); 138 | RETURN NULL; 139 | END IF; 140 | END get; 141 | 142 | ---------------------------------------------------------- 143 | -- exist 144 | -- 145 | MEMBER FUNCTION exist(SELF IN jsonArray, thePropertyIndex IN NUMBER) RETURN BOOLEAN 146 | IS 147 | BEGIN 148 | RETURN (json_utils.getNodeIDByIndex(theNodes=>SELF.nodes, thePropertyIndex=>thePropertyIndex) IS NOT NULL); 149 | END exist; 150 | 151 | ---------------------------------------------------------- 152 | -- to_clob_value 153 | -- 154 | MEMBER FUNCTION to_jsonValue(self IN jsonArray) RETURN jsonValue 155 | IS 156 | BEGIN 157 | RETURN jsonValue(json_utils.NODE_TYPE_ARRAY, SELF.nodes); 158 | END to_jsonValue; 159 | 160 | ---------------------------------------------------------- 161 | -- to_clob 162 | -- 163 | MEMBER PROCEDURE to_clob(SELF IN jsonArray, theLobBuf IN OUT NOCOPY CLOB, theEraseLob BOOLEAN DEFAULT TRUE) 164 | IS 165 | aIndentation INTEGER := 0; 166 | aStrBuf VARCHAR2(32767); 167 | BEGIN 168 | IF (theEraseLob) THEN 169 | json_utils.erase_clob(theLobBuf); 170 | END IF; 171 | json_utils.array_to_clob(theLobBuf=>theLobBuf, theStrBuf=>aStrBuf, theNodes=>SELF.nodes, theNodeID=>SELF.nodes.FIRST, theIndentation=>aIndentation); 172 | END to_clob; 173 | 174 | ---------------------------------------------------------- 175 | -- to_text 176 | -- 177 | MEMBER FUNCTION to_text(SELF IN jsonArray) RETURN VARCHAR2 178 | IS 179 | aIndentation INTEGER := 0; 180 | aStrBuf VARCHAR2(32767); 181 | aLobLoc CLOB; 182 | BEGIN 183 | dbms_lob.createtemporary(lob_loc=>aLobLoc, cache=>TRUE, dur=>dbms_lob.session); 184 | json_utils.array_to_clob(theLobBuf=>aLobLoc, theStrBuf=>aStrBuf, theNodes=>SELF.nodes, theNodeID=>SELF.nodes.FIRST, theIndentation=>aIndentation); 185 | aStrBuf := dbms_lob.substr(aLobLoc, 32767, 1); 186 | dbms_lob.freetemporary(lob_loc=>aLobLoc); 187 | 188 | RETURN aStrBuf; 189 | END to_text; 190 | 191 | ---------------------------------------------------------- 192 | -- htp 193 | -- 194 | MEMBER PROCEDURE htp(SELF IN jsonArray, theJSONP IN VARCHAR2 DEFAULT NULL) 195 | IS 196 | aLob CLOB := empty_clob(); 197 | BEGIN 198 | dbms_lob.createtemporary(aLob, TRUE); 199 | self.to_clob(aLob); 200 | json_utils.htp_output_clob(aLob, theJSONP); 201 | dbms_lob.freetemporary(aLob); 202 | END htp; 203 | 204 | END; 205 | / 206 | -------------------------------------------------------------------------------- /jsonarray.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonArray IS OBJECT 3 | ( 4 | nodes jsonNodes, -- list of nodes 5 | lastID NUMBER, -- id of the last node in this (not sub objects) object 6 | 7 | -- Constructors 8 | CONSTRUCTOR FUNCTION jsonArray(self IN OUT NOCOPY jsonArray) RETURN self AS result, 9 | CONSTRUCTOR FUNCTION jsonArray(SELF IN OUT NOCOPY jsonArray, theData IN jsonValue) RETURN SELF AS result, 10 | 11 | -- Member setter methods 12 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray), 13 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN VARCHAR2), 14 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN CLOB), 15 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN NUMBER), 16 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN DATE), 17 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN BOOLEAN), 18 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN jsonObject), 19 | MEMBER PROCEDURE append(self IN OUT NOCOPY jsonArray, theValue IN jsonArray), 20 | 21 | -- Member getter methods 22 | MEMBER FUNCTION count(SELF IN jsonArray) RETURN NUMBER, 23 | MEMBER FUNCTION get(SELF IN jsonArray, thePropertyIndex IN NUMBER) RETURN jsonValue, 24 | MEMBER FUNCTION exist(SELF IN jsonArray, thePropertyIndex IN NUMBER) RETURN BOOLEAN, 25 | 26 | -- Member convertion methods 27 | MEMBER FUNCTION to_jsonValue(self IN jsonArray) RETURN jsonValue, 28 | 29 | -- Output methods 30 | MEMBER PROCEDURE to_clob(SELF IN jsonArray, theLobBuf IN OUT NOCOPY CLOB, theEraseLob BOOLEAN DEFAULT TRUE), 31 | MEMBER FUNCTION to_text(SELF IN jsonArray) RETURN VARCHAR2, 32 | MEMBER PROCEDURE htp(SELF IN jsonArray, theJSONP IN VARCHAR2 DEFAULT NULL) 33 | ); 34 | / 35 | -------------------------------------------------------------------------------- /jsonkeys.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonKeys AS TABLE OF VARCHAR2(2000); 3 | / 4 | -------------------------------------------------------------------------------- /jsonnode.tpb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE BODY jsonNode 3 | IS 4 | 5 | ---------------------------------------------------------- 6 | -- jsonNode 7 | -- 8 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode) RETURN SELF AS RESULT 9 | IS 10 | BEGIN 11 | SELF.typ := NULL; 12 | SELF.nam := NULL; 13 | SELF.str := NULL; 14 | SELF.lob := NULL; 15 | SELF.num := NULL; 16 | SELF.dat := NULL; 17 | SELF.par := NULL; 18 | SELF.nex := NULL; 19 | SELF.sub := NULL; 20 | RETURN; 21 | END jsonNode; 22 | 23 | ---------------------------------------------------------- 24 | -- jsonNode (NULL) 25 | -- 26 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2) RETURN SELF AS RESULT 27 | IS 28 | BEGIN 29 | SELF.typ := json_utils.NODE_TYPE_NULL; 30 | SELF.nam := theName; 31 | SELF.str := NULL; 32 | SELF.lob := NULL; 33 | SELF.num := NULL; 34 | SELF.dat := NULL; 35 | SELF.par := NULL; 36 | SELF.nex := NULL; 37 | SELF.sub := NULL; 38 | RETURN; 39 | END jsonNode; 40 | 41 | ---------------------------------------------------------- 42 | -- jsonNode (VARCHAR2) 43 | -- 44 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN VARCHAR2) RETURN SELF AS RESULT 45 | IS 46 | BEGIN 47 | SELF.typ := json_utils.NODE_TYPE_STRING; 48 | SELF.nam := theName; 49 | SELF.str := theValue; 50 | SELF.lob := NULL; 51 | SELF.num := NULL; 52 | SELF.dat := NULL; 53 | SELF.par := NULL; 54 | SELF.nex := NULL; 55 | SELF.sub := NULL; 56 | RETURN; 57 | END jsonNode; 58 | 59 | ---------------------------------------------------------- 60 | -- jsonNode (CLOB) 61 | -- 62 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN CLOB) RETURN SELF AS RESULT 63 | IS 64 | BEGIN 65 | SELF.typ := json_utils.NODE_TYPE_LOB; 66 | SELF.nam := theName; 67 | SELF.str := NULL; 68 | SELF.lob := empty_clob(); 69 | SELF.num := NULL; 70 | SELF.dat := NULL; 71 | SELF.par := NULL; 72 | SELF.nex := NULL; 73 | SELF.sub := NULL; 74 | 75 | dbms_lob.createtemporary(lob_loc=>SELF.lob, cache=>TRUE, dur=>dbms_lob.session); 76 | IF (dbms_lob.getlength(lob_loc=>theValue) > 0) THEN 77 | dbms_lob.append(dest_lob=>SELF.lob, src_lob=>theValue); 78 | END IF; 79 | 80 | RETURN; 81 | END jsonNode; 82 | 83 | ---------------------------------------------------------- 84 | -- jsonNode (NUMBER) 85 | -- 86 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN NUMBER) RETURN SELF AS RESULT 87 | IS 88 | BEGIN 89 | SELF.typ := CASE WHEN theValue IS NOT NULL THEN json_utils.NODE_TYPE_NUMBER ELSE json_utils.NODE_TYPE_NULL END; 90 | SELF.nam := theName; 91 | SELF.str := NULL; 92 | SELF.lob := NULL; 93 | SELF.num := theValue; 94 | SELF.dat := NULL; 95 | SELF.par := NULL; 96 | SELF.nex := NULL; 97 | SELF.sub := NULL; 98 | RETURN; 99 | END jsonNode; 100 | 101 | ---------------------------------------------------------- 102 | -- jsonNode (DATE) 103 | -- 104 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN DATE) RETURN SELF AS RESULT 105 | IS 106 | BEGIN 107 | SELF.typ := CASE WHEN theValue IS NOT NULL THEN json_utils.NODE_TYPE_DATE ELSE json_utils.NODE_TYPE_NULL END; 108 | SELF.nam := theName; 109 | SELF.str := NULL; 110 | SELF.lob := NULL; 111 | SELF.num := NULL; 112 | SELF.dat := theValue; 113 | SELF.par := NULL; 114 | SELF.nex := NULL; 115 | SELF.sub := NULL; 116 | RETURN; 117 | END jsonNode; 118 | 119 | ---------------------------------------------------------- 120 | -- jsonNode (BOOLEAN) 121 | -- 122 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN BOOLEAN) RETURN SELF AS RESULT 123 | IS 124 | aNumber NUMBER; 125 | BEGIN 126 | IF (theValue IS NOT NULL) THEN 127 | aNumber := CASE theValue WHEN TRUE THEN 1 ELSE 0 END; 128 | END IF; 129 | 130 | SELF.typ := CASE WHEN theValue IS NOT NULL THEN json_utils.NODE_TYPE_BOOLEAN ELSE json_utils.NODE_TYPE_NULL END; 131 | SELF.nam := theName; 132 | SELF.str := NULL; 133 | SELF.lob := NULL; 134 | SELF.num := aNumber; 135 | SELF.dat := NULL; 136 | SELF.par := NULL; 137 | SELF.nex := NULL; 138 | SELF.sub := NULL; 139 | RETURN; 140 | END jsonNode; 141 | 142 | END; 143 | / 144 | -------------------------------------------------------------------------------- /jsonnode.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonNode IS OBJECT 3 | ( 4 | typ CHAR(1), -- 0=null, S=string, N=number, B=boolean, O=Object, A=array 5 | nam VARCHAR2(32767), -- property name (only in an object and NULL in an array) 6 | str VARCHAR2(32767), -- property value for string 7 | lob CLOB, -- property value for clob 8 | num NUMBER, -- property value for number and boolean where boolean is stored as 0 for FALSE and 1 for TRUE 9 | dat DATE, -- property value for date 10 | par NUMBER, -- id of the parent node or NULL if this is the root node 11 | nex NUMBER, -- id of the next node or NULL if this is the last node in this object 12 | sub NUMBER, -- id of the jsonNode when type is an object or an array 13 | 14 | -- Default constructor 15 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode) RETURN SELF AS RESULT, 16 | 17 | -- Constructors 18 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2) RETURN SELF AS RESULT, 19 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN VARCHAR2) RETURN SELF AS RESULT, 20 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN CLOB) RETURN SELF AS RESULT, 21 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN NUMBER) RETURN SELF AS RESULT, 22 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN DATE) RETURN SELF AS RESULT, 23 | CONSTRUCTOR FUNCTION jsonNode(SELF IN OUT NOCOPY jsonNode, theName IN VARCHAR2, theValue IN BOOLEAN) RETURN SELF AS RESULT 24 | ); 25 | / 26 | -------------------------------------------------------------------------------- /jsonnodes.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonNodes AS TABLE OF jsonNode; 3 | / 4 | -------------------------------------------------------------------------------- /jsonobject.tpb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE BODY jsonObject IS 3 | 4 | ---------------------------------------------------------- 5 | -- jsonObject 6 | -- 7 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject) RETURN SELF AS result 8 | IS 9 | BEGIN 10 | SELF.nodes := jsonNodes(); 11 | SELF.lastID := NULL; 12 | RETURN; 13 | END jsonObject; 14 | 15 | ---------------------------------------------------------- 16 | -- jsonObject 17 | -- 18 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject, theData IN jsonValue) RETURN SELF AS result 19 | IS 20 | BEGIN 21 | IF (theData.typ != json_utils.NODE_TYPE_OBJECT) THEN 22 | raise_application_error(-20100, 'jsonObject exception: unable to convert node ('||theData.typ||') to an object'); 23 | ELSE 24 | SELF.nodes := theData.nodes; 25 | SELF.lastID := NULL; 26 | END IF; 27 | RETURN; 28 | END jsonObject; 29 | 30 | ---------------------------------------------------------- 31 | -- jsonObject 32 | -- 33 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject, theJSONString IN CLOB) RETURN SELF AS result 34 | IS 35 | BEGIN 36 | SELF.nodes := json_parser.parser(theJSONString); 37 | SELF.lastID := NULL; 38 | RETURN; 39 | END jsonObject; 40 | 41 | ---------------------------------------------------------- 42 | -- put 43 | -- 44 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2) 45 | IS 46 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 47 | BEGIN 48 | -- remove the existing node if we change an existing property 49 | IF (aNodeID IS NOT NULL) THEN 50 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 51 | END IF; 52 | 53 | -- add the node 54 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName)); 55 | END put; 56 | 57 | ---------------------------------------------------------- 58 | -- put (VARCHAR2) 59 | -- 60 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN VARCHAR2) 61 | IS 62 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 63 | BEGIN 64 | -- remove the existing node if we change an existing property 65 | IF (aNodeID IS NOT NULL) THEN 66 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 67 | END IF; 68 | 69 | -- add the node 70 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName, theValue)); 71 | END put; 72 | 73 | ---------------------------------------------------------- 74 | -- put (CLOB) 75 | -- 76 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN CLOB) 77 | IS 78 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 79 | BEGIN 80 | -- remove the existing node if we change an existing property 81 | IF (aNodeID IS NOT NULL) THEN 82 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 83 | END IF; 84 | 85 | -- add the node 86 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName, theValue)); 87 | END put; 88 | 89 | ---------------------------------------------------------- 90 | -- put (NUMBER) 91 | -- 92 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN NUMBER) 93 | IS 94 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 95 | BEGIN 96 | -- remove the existing node if we change an existing property 97 | IF (aNodeID IS NOT NULL) THEN 98 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 99 | END IF; 100 | 101 | -- add the node 102 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName, theValue)); 103 | END put; 104 | 105 | ---------------------------------------------------------- 106 | -- put (DATE) 107 | -- 108 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN DATE) 109 | IS 110 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 111 | BEGIN 112 | -- remove the existing node if we change an existing property 113 | IF (aNodeID IS NOT NULL) THEN 114 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 115 | END IF; 116 | 117 | -- add the node 118 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName, theValue)); 119 | END put; 120 | 121 | ---------------------------------------------------------- 122 | -- put (BOOLEAN) 123 | -- 124 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN BOOLEAN) 125 | IS 126 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 127 | BEGIN 128 | -- remove the existing node if we change an existing property 129 | IF (aNodeID IS NOT NULL) THEN 130 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 131 | END IF; 132 | 133 | -- add the node 134 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theName, theValue)); 135 | END put; 136 | 137 | ---------------------------------------------------------- 138 | -- put 139 | -- 140 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN jsonObject) 141 | IS 142 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 143 | BEGIN 144 | -- remove the existing node if we change an existing property 145 | IF (aNodeID IS NOT NULL) THEN 146 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 147 | END IF; 148 | 149 | -- add a new object node that will be used as the root for all the sub notes 150 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(json_utils.NODE_TYPE_OBJECT, theName, NULL, NULL, NULL, NULL, NULL, NULL, NULL)); 151 | 152 | -- copy the sub-nodes 153 | json_utils.copyNodes(theTargetNodes=>SELF.nodes, theTargetNodeID=>aNodeID, theLastID=>SELF.lastID, theName=>theName, theSourceNodes=>theValue.nodes); 154 | END put; 155 | 156 | ---------------------------------------------------------- 157 | -- put 158 | -- 159 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN jsonValue) 160 | IS 161 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>theName); 162 | BEGIN 163 | -- remove the existing node if we change an existing property 164 | IF (aNodeID IS NOT NULL) THEN 165 | SELF.lastID := json_utils.removeNode(theNodes=>SELF.nodes, theNodeID=>aNodeID); 166 | END IF; 167 | 168 | -- add a new object node that will be used as the root for all the sub notes 169 | aNodeID := json_utils.addNode(theNodes=>SELF.nodes, theLastID=>SELF.lastID, theNode=>jsonNode(theValue.typ, theName, NULL, NULL, NULL, NULL, NULL, NULL, NULL)); 170 | 171 | -- copy the sub-nodes 172 | json_utils.copyNodes(theTargetNodes=>SELF.nodes, theTargetNodeID=>aNodeID, theLastID=>SELF.lastID, theName=>theName, theSourceNodes=>theValue.nodes); 173 | END put; 174 | 175 | ---------------------------------------------------------- 176 | -- count 177 | -- 178 | MEMBER FUNCTION count(SELF IN jsonObject) RETURN NUMBER 179 | IS 180 | BEGIN 181 | RETURN json_utils.getNodeCount(theNodes=>SELF.nodes); 182 | END count; 183 | 184 | ---------------------------------------------------------- 185 | -- get 186 | -- 187 | MEMBER FUNCTION get(SELF IN jsonObject, thePropertyName IN VARCHAR2) RETURN jsonValue 188 | IS 189 | aNodeID BINARY_INTEGER := json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>thePropertyName); 190 | BEGIN 191 | IF (aNodeID IS NOT NULL) THEN 192 | RETURN json_utils.createSubTree(theSourceNodes=>SELF.nodes, theSourceNodeID=>aNodeID); 193 | ELSE 194 | raise_application_error(-20100, 'jsonObject exception: property ('||thePropertyName||') does not exit'); 195 | RETURN NULL; 196 | END IF; 197 | END get; 198 | 199 | ---------------------------------------------------------- 200 | -- exist 201 | -- 202 | MEMBER FUNCTION exist(SELF IN jsonObject, thePropertyName IN VARCHAR2) RETURN BOOLEAN 203 | IS 204 | BEGIN 205 | RETURN (json_utils.getNodeIDByName(theNodes=>SELF.nodes, thePropertyName=>thePropertyName) IS NOT NULL); 206 | END exist; 207 | 208 | ---------------------------------------------------------- 209 | -- get_keys 210 | -- 211 | MEMBER FUNCTION get_keys RETURN jsonKeys 212 | IS 213 | keys jsonKeys := jsonKeys(); 214 | i BINARY_INTEGER := SELF.nodes.FIRST; 215 | BEGIN 216 | WHILE (i IS NOT NULL) LOOP 217 | keys.EXTEND(1); 218 | keys(keys.LAST) := SELF.nodes(i).nam; 219 | i := SELF.nodes(i).nex; 220 | END LOOP; 221 | 222 | RETURN keys; 223 | END get_keys; 224 | 225 | ---------------------------------------------------------- 226 | -- to_jsonValue 227 | -- 228 | MEMBER FUNCTION to_jsonValue(SELF IN jsonObject) RETURN jsonValue 229 | IS 230 | BEGIN 231 | RETURN jsonValue(json_utils.NODE_TYPE_OBJECT, SELF.nodes); 232 | END to_jsonValue; 233 | 234 | ---------------------------------------------------------- 235 | -- to_clob 236 | -- 237 | MEMBER PROCEDURE to_clob(SELF IN jsonObject, theLobBuf IN OUT NOCOPY CLOB, theEraseLob BOOLEAN DEFAULT TRUE) 238 | IS 239 | aIndentation INTEGER := 0; 240 | aStrBuf VARCHAR2(32767); 241 | BEGIN 242 | IF (theEraseLob) THEN 243 | json_utils.erase_clob(theLobBuf); 244 | END IF; 245 | json_utils.object_to_clob(theLobBuf=>theLobBuf, theStrBuf=>aStrBuf, theNodes=>SELF.nodes, theNodeID=>SELF.nodes.FIRST, theIndentation=>aIndentation); 246 | END to_clob; 247 | 248 | ---------------------------------------------------------- 249 | -- to_text 250 | -- 251 | MEMBER FUNCTION to_text(SELF IN jsonObject) RETURN VARCHAR2 252 | IS 253 | aIndentation INTEGER := 0; 254 | aStrBuf VARCHAR2(32767); 255 | aLobLoc CLOB; 256 | BEGIN 257 | dbms_lob.createtemporary(lob_loc=>aLobLoc, cache=>TRUE, dur=>dbms_lob.session); 258 | json_utils.object_to_clob(theLobBuf=>aLobLoc, theStrBuf=>aStrBuf, theNodes=>SELF.nodes, theNodeID=>SELF.nodes.FIRST, theIndentation=>aIndentation); 259 | aStrBuf := dbms_lob.substr(aLobLoc, 32767, 1); 260 | dbms_lob.freetemporary(lob_loc=>aLobLoc); 261 | 262 | RETURN aStrBuf; 263 | END to_text; 264 | 265 | ---------------------------------------------------------- 266 | -- htp 267 | -- 268 | MEMBER PROCEDURE htp(SELF IN jsonObject, theJSONP IN VARCHAR2 DEFAULT NULL) 269 | IS 270 | aLob CLOB := empty_clob(); 271 | BEGIN 272 | dbms_lob.createtemporary(aLob, TRUE); 273 | SELF.to_clob(aLob); 274 | json_utils.htp_output_clob(aLob, theJSONP); 275 | dbms_lob.freetemporary(aLob); 276 | END htp; 277 | 278 | END; 279 | / 280 | -------------------------------------------------------------------------------- /jsonobject.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonObject IS OBJECT 3 | 4 | -- $Id: jsonobject.tps 56520 2019-02-11 22:52:31Z doberkofler $ 5 | 6 | ------------ 7 | -- OVERVIEW 8 | -- 9 | -- Utilities to efficiently generate JSON 10 | -- 11 | -- 12 | 13 | ----------- 14 | -- EXAMPLE 15 | -- 16 | -- 17 | -- DECLARE 18 | -- aNameObj jsonObject := jsonObject(); 19 | -- aEmailArray jsonArray := jsonArray(); 20 | -- aPersonObj jsonObject := jsonObject(); 21 | -- aPersonArray jsonArray := jsonArray(); 22 | -- 23 | -- -- just for debugging 24 | -- aLob CLOB := empty_clob(); 25 | -- BEGIN 26 | -- FOR i IN 1 .. 3 LOOP 27 | -- aNameObj := jsonObject(); 28 | -- aNameObj.put('given', 'Jon'); 29 | -- aNameObj.put('last', 'Doe'); 30 | -- 31 | -- aEmailArray := jsonArray(); 32 | -- aEmailArray.append('jon.doe@gmail.com'); 33 | -- aEmailArray.append('j.doe@gmail.com'); 34 | -- 35 | -- aPersonObj := jsonObject(); 36 | -- aPersonObj.put('id', i); 37 | -- aPersonObj.put('name', aNameObj); 38 | -- aPersonObj.put('income', 4800 + i * 100); 39 | -- aPersonObj.put('birthday', SYSDATE); 40 | -- aPersonObj.put('male', TRUE); 41 | -- aPersonObj.put('voice', aEmailArray.to_jsonValue()); 42 | -- 43 | -- aPersonArray.append(i); 44 | -- aPersonArray.append(3.14); 45 | -- aPersonArray.append(FALSE); 46 | -- aPersonArray.append(aPersonObj); 47 | -- END LOOP; 48 | -- 49 | -- aPersonArray.htp(); 50 | -- 51 | -- -- just for debugging 52 | -- dbms_lob.createtemporary(aLob, TRUE); 53 | -- aPersonArray.to_clob(aLob); 54 | -- dbms_output.put_line(aLob); 55 | -- dbms_lob.freetemporary(aLob); 56 | -- END; 57 | -- / 58 | -- 59 | 60 | 61 | ------------- 62 | -- RESOURCES 63 | -- 64 | -- You must use the following modules together: 65 | -- jsonNode (TYPE) 66 | -- jsonNodes (TYPE) 67 | -- json_data (TYPE) 68 | -- jsonObject (TYPE) 69 | -- jsonArray (TYPE) 70 | -- json_utils (PACKAGE) 71 | -- 72 | -- 73 | 74 | ( 75 | nodes jsonNodes, -- list of nodes 76 | lastID NUMBER, -- id of the last node in this (not sub objects) object 77 | 78 | -- Constructors 79 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject) RETURN SELF AS result, 80 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject, theData IN jsonValue) RETURN SELF AS result, 81 | CONSTRUCTOR FUNCTION jsonObject(SELF IN OUT NOCOPY jsonObject, theJSONString IN CLOB) RETURN SELF AS result, 82 | 83 | -- Member setter methods 84 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2), 85 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN VARCHAR2), 86 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN CLOB), 87 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN NUMBER), 88 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN DATE), 89 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN BOOLEAN), 90 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN jsonObject), 91 | MEMBER PROCEDURE put(SELF IN OUT NOCOPY jsonObject, theName IN VARCHAR2, theValue IN jsonValue), 92 | 93 | -- Member getter methods 94 | MEMBER FUNCTION count(SELF IN jsonObject) RETURN NUMBER, 95 | MEMBER FUNCTION get(SELF IN jsonObject, thePropertyName IN VARCHAR2) RETURN jsonValue, 96 | MEMBER FUNCTION exist(SELF IN jsonObject, thePropertyName IN VARCHAR2) RETURN BOOLEAN, 97 | MEMBER FUNCTION get_keys RETURN jsonKeys, 98 | 99 | -- Member convertion methods 100 | MEMBER FUNCTION to_jsonValue(SELF IN jsonObject) RETURN jsonValue, 101 | 102 | -- Output methods 103 | MEMBER PROCEDURE to_clob(SELF IN jsonObject, theLobBuf IN OUT NOCOPY CLOB, theEraseLob BOOLEAN DEFAULT TRUE), 104 | MEMBER FUNCTION to_text(SELF IN jsonObject) RETURN VARCHAR2, 105 | MEMBER PROCEDURE htp(SELF IN jsonObject, theJSONP IN VARCHAR2 DEFAULT NULL) 106 | ); 107 | / 108 | -------------------------------------------------------------------------------- /jsonvalue.tpb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE BODY jsonValue 3 | IS 4 | 5 | 6 | ---------------------------------------------------------- 7 | -- jsonValue 8 | -- 9 | CONSTRUCTOR FUNCTION jsonValue(SELF IN OUT NOCOPY jsonValue) RETURN SELF AS RESULT 10 | IS 11 | BEGIN 12 | SELF.typ := NULL; 13 | SELF.nodes := jsonNodes(); 14 | RETURN; 15 | END jsonValue; 16 | 17 | ---------------------------------------------------------- 18 | -- get_type 19 | -- 20 | MEMBER FUNCTION get_type RETURN VARCHAR2 21 | IS 22 | BEGIN 23 | IF (SELF.typ IS NULL) THEN 24 | CASE SELF.nodes(1).typ 25 | WHEN json_utils.NODE_TYPE_NULL THEN RETURN 'NULL'; 26 | WHEN json_utils.NODE_TYPE_STRING THEN RETURN 'STRING'; 27 | WHEN json_utils.NODE_TYPE_LOB THEN RETURN 'LOB'; 28 | WHEN json_utils.NODE_TYPE_NUMBER THEN RETURN 'NUMBER'; 29 | WHEN json_utils.NODE_TYPE_DATE THEN RETURN 'DATE'; 30 | WHEN json_utils.NODE_TYPE_BOOLEAN THEN RETURN 'BOOLEAN'; 31 | ELSE 32 | raise_application_error(-20100, 'jsonNode exception: node type ('||SELF.nodes(1).typ||') invalid'); 33 | RETURN NULL; 34 | END CASE; 35 | ELSIF (SELF.typ = json_utils.NODE_TYPE_OBJECT) THEN 36 | RETURN 'OBJECT'; 37 | ELSIF (SELF.typ = json_utils.NODE_TYPE_ARRAY) THEN 38 | RETURN 'ARRAY'; 39 | ELSE 40 | raise_application_error(-20100, 'jsonNode exception: node type ('||SELF.typ||') invalid'); 41 | RETURN NULL; 42 | END IF; 43 | END get_type; 44 | 45 | ---------------------------------------------------------- 46 | -- get_name 47 | -- 48 | MEMBER FUNCTION get_name RETURN VARCHAR2 49 | IS 50 | BEGIN 51 | RETURN SELF.nodes(1).nam; 52 | END get_name; 53 | 54 | ---------------------------------------------------------- 55 | -- get_string 56 | -- 57 | MEMBER FUNCTION get_string RETURN VARCHAR2 58 | IS 59 | BEGIN 60 | IF (SELF.is_string()) THEN 61 | RETURN SELF.nodes(1).str; 62 | ELSIF (SELF.is_lob()) THEN 63 | IF (dbms_lob.getlength(lob_loc=>SELF.nodes(1).lob) <= 32767) THEN 64 | RETURN SELF.nodes(1).lob; 65 | ELSE 66 | raise_application_error(-20100, 'jsonNode exception: attempt to get a lob > 32767 as a string'); 67 | RETURN NULL; 68 | END IF; 69 | ELSE 70 | raise_application_error(-20100, 'jsonNode exception: attempt to get a string from a node with type ('||SELF.get_type||')'); 71 | RETURN NULL; 72 | END IF; 73 | END get_string; 74 | 75 | ---------------------------------------------------------- 76 | -- get_lob 77 | -- 78 | MEMBER FUNCTION get_lob RETURN CLOB 79 | IS 80 | BEGIN 81 | IF (SELF.is_lob()) THEN 82 | RETURN SELF.nodes(1).lob; 83 | ELSIF (SELF.is_string()) THEN 84 | RETURN TO_CLOB(SELF.nodes(1).str); 85 | ELSE 86 | raise_application_error(-20100, 'jsonNode exception: attempt to get a lob from a node with type ('||SELF.get_type||')'); 87 | RETURN NULL; 88 | END IF; 89 | END get_lob; 90 | 91 | ---------------------------------------------------------- 92 | -- get_number 93 | -- 94 | MEMBER FUNCTION get_number RETURN NUMBER 95 | IS 96 | BEGIN 97 | IF (SELF.is_number()) THEN 98 | RETURN SELF.nodes(1).num; 99 | ELSE 100 | raise_application_error(-20100, 'jsonNode exception: attempt to get a number from a node with type ('||SELF.get_type||')'); 101 | RETURN NULL; 102 | END IF; 103 | END get_number; 104 | 105 | ---------------------------------------------------------- 106 | -- get_date 107 | -- 108 | MEMBER FUNCTION get_date RETURN DATE 109 | IS 110 | BEGIN 111 | IF (SELF.is_date()) THEN 112 | RETURN SELF.nodes(1).dat; 113 | ELSE 114 | raise_application_error(-20100, 'jsonNode exception: attempt to get a date from a node with type ('||SELF.get_type||')'); 115 | RETURN NULL; 116 | END IF; 117 | END get_date; 118 | 119 | ---------------------------------------------------------- 120 | -- get_bool 121 | -- 122 | MEMBER FUNCTION get_bool RETURN BOOLEAN 123 | IS 124 | BEGIN 125 | IF (SELF.is_bool()) THEN 126 | RETURN (SELF.nodes(1).num = 1); 127 | ELSE 128 | raise_application_error(-20100, 'jsonNode exception: attempt to get a boolean from a node with type ('||SELF.get_type||')'); 129 | RETURN NULL; 130 | END IF; 131 | END get_bool; 132 | 133 | ---------------------------------------------------------- 134 | -- is_object 135 | -- 136 | MEMBER FUNCTION is_object RETURN BOOLEAN 137 | IS 138 | BEGIN 139 | RETURN (SELF.get_type = 'OBJECT'); 140 | END is_object; 141 | 142 | ---------------------------------------------------------- 143 | -- is_array 144 | -- 145 | MEMBER FUNCTION is_array RETURN BOOLEAN 146 | IS 147 | BEGIN 148 | RETURN (SELF.get_type = 'ARRAY'); 149 | END is_array; 150 | 151 | ---------------------------------------------------------- 152 | -- is_string 153 | -- 154 | MEMBER FUNCTION is_string RETURN BOOLEAN 155 | IS 156 | BEGIN 157 | RETURN (SELF.get_type = 'STRING'); 158 | END is_string; 159 | 160 | ---------------------------------------------------------- 161 | -- is_lob 162 | -- 163 | MEMBER FUNCTION is_lob RETURN BOOLEAN 164 | IS 165 | BEGIN 166 | RETURN (SELF.get_type = 'LOB'); 167 | END is_lob; 168 | 169 | ---------------------------------------------------------- 170 | -- is_number 171 | -- 172 | MEMBER FUNCTION is_number RETURN BOOLEAN 173 | IS 174 | BEGIN 175 | RETURN (SELF.get_type = 'NUMBER'); 176 | END is_number; 177 | 178 | ---------------------------------------------------------- 179 | -- is_date 180 | -- 181 | MEMBER FUNCTION is_date RETURN BOOLEAN 182 | IS 183 | BEGIN 184 | RETURN (SELF.get_type = 'DATE'); 185 | END is_date; 186 | 187 | ---------------------------------------------------------- 188 | -- is_bool 189 | -- 190 | MEMBER FUNCTION is_bool RETURN BOOLEAN 191 | IS 192 | BEGIN 193 | RETURN (SELF.get_type = 'BOOLEAN'); 194 | END is_bool; 195 | 196 | ---------------------------------------------------------- 197 | -- is_null 198 | -- 199 | MEMBER FUNCTION is_null RETURN BOOLEAN 200 | IS 201 | BEGIN 202 | RETURN (SELF.get_type = 'NULL'); 203 | END is_null; 204 | 205 | 206 | END; 207 | / 208 | -------------------------------------------------------------------------------- /jsonvalue.tps: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | TYPE jsonValue IS OBJECT 3 | ( 4 | typ VARCHAR(1), -- O=Object, A=array or NULL for all other basic types 5 | nodes jsonNodes, -- if typ is NULL the actual type is in the first and only node of the list 6 | 7 | -- Default constructor 8 | CONSTRUCTOR FUNCTION jsonValue(SELF IN OUT NOCOPY jsonValue) RETURN SELF AS RESULT, 9 | 10 | -- Member getter methods 11 | MEMBER FUNCTION get_type RETURN VARCHAR2, 12 | MEMBER FUNCTION get_name RETURN VARCHAR2, 13 | 14 | MEMBER FUNCTION get_string RETURN VARCHAR2, 15 | MEMBER FUNCTION get_lob RETURN CLOB, 16 | MEMBER FUNCTION get_number RETURN NUMBER, 17 | MEMBER FUNCTION get_date RETURN DATE, 18 | MEMBER FUNCTION get_bool RETURN BOOLEAN, 19 | 20 | MEMBER FUNCTION is_object RETURN BOOLEAN, 21 | MEMBER FUNCTION is_array RETURN BOOLEAN, 22 | MEMBER FUNCTION is_string RETURN BOOLEAN, 23 | MEMBER FUNCTION is_lob RETURN BOOLEAN, 24 | MEMBER FUNCTION is_number RETURN BOOLEAN, 25 | MEMBER FUNCTION is_date RETURN BOOLEAN, 26 | MEMBER FUNCTION is_bool RETURN BOOLEAN, 27 | MEMBER FUNCTION is_null RETURN BOOLEAN 28 | ); 29 | / 30 | -------------------------------------------------------------------------------- /uninstall.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * 3 | * NAME 4 | * uninstall.sql 5 | * 6 | * AUTHOR 7 | * Dieter Oberkofler 8 | * 9 | * FUNCTION 10 | * Uninstall the plsql_json objects 11 | * 12 | */ 13 | 14 | DECLARE 15 | object_does_not_exist EXCEPTION; 16 | PRAGMA EXCEPTION_INIT(object_does_not_exist, -4043); 17 | BEGIN 18 | BEGIN 19 | EXECUTE IMMEDIATE 'DROP TYPE jsonArray FORCE'; 20 | EXCEPTION 21 | WHEN object_does_not_exist THEN NULL; 22 | END; 23 | 24 | BEGIN 25 | EXECUTE IMMEDIATE 'DROP TYPE jsonObject FORCE'; 26 | EXCEPTION 27 | WHEN object_does_not_exist THEN NULL; 28 | END; 29 | 30 | BEGIN 31 | EXECUTE IMMEDIATE 'DROP TYPE jsonValue FORCE'; 32 | EXCEPTION 33 | WHEN object_does_not_exist THEN NULL; 34 | END; 35 | 36 | BEGIN 37 | EXECUTE IMMEDIATE 'DROP TYPE jsonNodes FORCE'; 38 | EXCEPTION 39 | WHEN object_does_not_exist THEN NULL; 40 | END; 41 | 42 | BEGIN 43 | EXECUTE IMMEDIATE 'DROP TYPE jsonNode FORCE'; 44 | EXCEPTION 45 | WHEN object_does_not_exist THEN NULL; 46 | END; 47 | 48 | BEGIN 49 | EXECUTE IMMEDIATE 'DROP TYPE jsonKeys FORCE'; 50 | EXCEPTION 51 | WHEN object_does_not_exist THEN NULL; 52 | END; 53 | 54 | BEGIN 55 | EXECUTE IMMEDIATE 'DROP PACKAGE json_utils'; 56 | EXCEPTION 57 | WHEN object_does_not_exist THEN NULL; 58 | END; 59 | 60 | BEGIN 61 | EXECUTE IMMEDIATE 'DROP PACKAGE json_parser'; 62 | EXCEPTION 63 | WHEN object_does_not_exist THEN NULL; 64 | END; 65 | 66 | BEGIN 67 | EXECUTE IMMEDIATE 'DROP PACKAGE json_sql'; 68 | EXCEPTION 69 | WHEN object_does_not_exist THEN NULL; 70 | END; 71 | 72 | BEGIN 73 | EXECUTE IMMEDIATE 'DROP PACKAGE json_debug'; 74 | EXCEPTION 75 | WHEN object_does_not_exist THEN NULL; 76 | END; 77 | END; 78 | / 79 | -------------------------------------------------------------------------------- /unittest/UT_util.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY UT_util IS 3 | 4 | ---------------------------------------------------------- 5 | -- PRIVATE TYPES 6 | ---------------------------------------------------------- 7 | 8 | 9 | ---------------------------------------------------------- 10 | -- PRIVATE VARIABLES 11 | ---------------------------------------------------------- 12 | 13 | CurrentModule VARCHAR2(2000); 14 | 15 | 16 | ---------------------------------------------------------- 17 | -- LOCAL MODULES 18 | ---------------------------------------------------------- 19 | 20 | PROCEDURE reportSuccess(theTitle IN VARCHAR2, theTest IN VARCHAR2, theExpected IN CLOB, theComputed IN CLOB); 21 | PROCEDURE reportFailure(theTitle IN VARCHAR2, theTest IN VARCHAR2, theExpected IN CLOB, theComputed IN CLOB); 22 | PROCEDURE console(theText IN VARCHAR2 DEFAULT NULL); 23 | 24 | 25 | ---------------------------------------------------------- 26 | -- GLOBAL MODULES 27 | ---------------------------------------------------------- 28 | 29 | 30 | ---------------------------------------------------------- 31 | -- module 32 | -- 33 | PROCEDURE module(theModule IN VARCHAR2) 34 | IS 35 | BEGIN 36 | CurrentModule := theModule; 37 | END module; 38 | 39 | ---------------------------------------------------------- 40 | -- eq 41 | -- 42 | PROCEDURE eq( theTitle IN VARCHAR2, 43 | theExpected IN VARCHAR2, 44 | theComputed IN VARCHAR2, 45 | theNullOK IN BOOLEAN DEFAULT FALSE 46 | ) 47 | IS 48 | aOK BOOLEAN; 49 | aTest CLOB; 50 | BEGIN 51 | aOK := (NVL(theExpected = theComputed, FALSE)) OR (theExpected IS NULL AND theComputed IS NULL AND theNullOK); 52 | aTest := 'EQ(VARCHAR2): expected="' || asString(theExpected) || '" computed="' || asString(theComputed) || '" Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 53 | 54 | IF (aOK) THEN 55 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 56 | ELSE 57 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 58 | END IF; 59 | END eq; 60 | 61 | ---------------------------------------------------------- 62 | -- eq 63 | -- 64 | PROCEDURE eq( theTitle IN VARCHAR2, 65 | theExpected IN BOOLEAN, 66 | theComputed IN BOOLEAN, 67 | theNullOK IN BOOLEAN DEFAULT FALSE 68 | ) 69 | IS 70 | aOK BOOLEAN; 71 | aTest CLOB; 72 | BEGIN 73 | aOK := (NVL(theExpected = theComputed, FALSE)) OR (theExpected IS NULL AND theComputed IS NULL AND theNullOK); 74 | aTest := 'EQ(BOOLEAN): expected="' || asString(theExpected) || '" computed="' || asString(theComputed) || '" Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 75 | 76 | IF (aOK) THEN 77 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 78 | ELSE 79 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 80 | END IF; 81 | END eq; 82 | 83 | ---------------------------------------------------------- 84 | -- Test for equality of NUMBER 85 | -- 86 | PROCEDURE eq( theTitle IN VARCHAR2, 87 | theExpected IN NUMBER, 88 | theComputed IN NUMBER, 89 | theNullOK IN BOOLEAN DEFAULT FALSE 90 | ) 91 | IS 92 | aOK BOOLEAN; 93 | aTest CLOB; 94 | BEGIN 95 | aOK := (NVL(theExpected = theComputed, FALSE)) OR (theExpected IS NULL AND theComputed IS NULL AND theNullOK); 96 | aTest := 'EQ(NUMBER): expected="' || asString(theExpected) || '" computed="' || asString(theComputed) || '" Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 97 | 98 | IF (aOK) THEN 99 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 100 | ELSE 101 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 102 | END IF; 103 | END eq; 104 | 105 | ---------------------------------------------------------- 106 | -- Test for equality of DATE 107 | -- 108 | PROCEDURE eq( theTitle IN VARCHAR2, 109 | theExpected IN DATE, 110 | theComputed IN DATE, 111 | theNullOK IN BOOLEAN DEFAULT FALSE 112 | ) 113 | IS 114 | aOK BOOLEAN; 115 | aTest CLOB; 116 | BEGIN 117 | aOK := (NVL(theExpected = theComputed, FALSE)) OR (theExpected IS NULL AND theComputed IS NULL AND theNullOK); 118 | aTest := 'EQ(DATE): expected="' || asString(theExpected) || '" computed="' || asString(theComputed) || '" Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 119 | 120 | IF (aOK) THEN 121 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 122 | ELSE 123 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>asString(theExpected), theComputed=>asString(theComputed)); 124 | END IF; 125 | END eq; 126 | 127 | ---------------------------------------------------------- 128 | -- Test for equality of CLOB 129 | -- 130 | PROCEDURE eqLOB(theTitle IN VARCHAR2, 131 | theExpected IN CLOB, 132 | theComputed IN CLOB, 133 | theNullOK IN BOOLEAN DEFAULT FALSE 134 | ) 135 | IS 136 | aOK BOOLEAN; 137 | aTest CLOB; 138 | aResult INTEGER; 139 | BEGIN 140 | -- are null allowed and are both lob's null ? 141 | IF (theNullOK AND theExpected IS NULL AND theComputed IS NULL) THEN 142 | aOK := TRUE; 143 | goto done; 144 | END IF; 145 | 146 | -- have both lob's a length of 0 147 | IF (dbms_lob.getlength(theExpected) = 0 AND dbms_lob.getlength(theComputed) = 0) THEN 148 | aOK := TRUE; 149 | goto done; 150 | END IF; 151 | 152 | -- compare the content of the lob's 153 | aResult := dbms_lob.compare(theExpected, theComputed); 154 | IF (aResult IS NULL) THEN 155 | RAISE VALUE_ERROR; 156 | END IF; 157 | aOK := (aResult = 0); 158 | 159 | -- format the results 160 | <> 161 | 162 | aTest := 'EQ(CLOB): expected:"' || asStringLOB(theExpected) || ' computed:' || asStringLOB(theComputed) || ' Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 163 | IF (aOK) THEN 164 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>theExpected, theComputed=>theComputed); 165 | ELSE 166 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>theExpected, theComputed=>theComputed); 167 | END IF; 168 | END eqLOB; 169 | 170 | ---------------------------------------------------------- 171 | -- Test for equality of BLOB 172 | -- 173 | PROCEDURE eqLOB(theTitle IN VARCHAR2, 174 | theExpected IN BLOB, 175 | theComputed IN BLOB, 176 | theNullOK IN BOOLEAN DEFAULT FALSE 177 | ) 178 | IS 179 | aOK BOOLEAN; 180 | aTest CLOB; 181 | aResult INTEGER; 182 | BEGIN 183 | -- are null allowed and are both lob's null ? 184 | IF (theNullOK AND theExpected IS NULL AND theComputed IS NULL) THEN 185 | aOK := TRUE; 186 | goto done; 187 | END IF; 188 | 189 | -- have both lob's a length of 0 190 | IF (dbms_lob.getlength(theExpected) = 0 AND dbms_lob.getlength(theComputed) = 0) THEN 191 | aOK := TRUE; 192 | goto done; 193 | END IF; 194 | 195 | -- compare the content of the lob's 196 | aResult := dbms_lob.compare(theExpected, theComputed); 197 | IF (aResult IS NULL) THEN 198 | RAISE VALUE_ERROR; 199 | END IF; 200 | aOK := (aResult = 0); 201 | 202 | -- format the results 203 | <> 204 | 205 | aTest := 'EQ(BLOB): expected:"' || asStringLOB(theExpected) || ' computed:' || asStringLOB(theComputed) || ' Null is OK: ' || CASE theNullOK WHEN TRUE THEN 'True' ELSE 'False' END || '.'; 206 | IF (aOK) THEN 207 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 208 | ELSE 209 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 210 | END IF; 211 | END eqLOB; 212 | 213 | ---------------------------------------------------------- 214 | -- ok 215 | -- 216 | PROCEDURE ok( theTitle IN VARCHAR2, 217 | theValue IN BOOLEAN 218 | ) 219 | IS 220 | aOK BOOLEAN; 221 | aTest CLOB; 222 | BEGIN 223 | aOK := NVL(theValue, FALSE); 224 | aTest := 'OK condition "' || asString(theValue) || '".'; 225 | 226 | IF (aOK) THEN 227 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 228 | ELSE 229 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 230 | END IF; 231 | END ok; 232 | 233 | ---------------------------------------------------------- 234 | -- ko 235 | -- 236 | PROCEDURE ko( theTitle IN VARCHAR2, 237 | theValue IN BOOLEAN 238 | ) 239 | IS 240 | aOK BOOLEAN; 241 | aTest CLOB; 242 | BEGIN 243 | aOK := NVL(theValue, FALSE); 244 | aTest := 'OK condition "' || asString(theValue) || '".'; 245 | 246 | IF (NOT aOK) THEN 247 | reportSuccess(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 248 | ELSE 249 | reportFailure(theTitle=>theTitle, theTest=>aTest, theExpected=>NULL, theComputed=>NULL); 250 | END IF; 251 | END ko; 252 | 253 | ---------------------------------------------------------- 254 | -- asString 255 | -- 256 | FUNCTION asString(theValue IN VARCHAR2) RETURN VARCHAR2 257 | IS 258 | BEGIN 259 | RETURN NVL(theValue, ''); 260 | END asString; 261 | 262 | ---------------------------------------------------------- 263 | -- asString 264 | -- 265 | FUNCTION asString(theValue IN NUMBER) RETURN VARCHAR2 266 | IS 267 | BEGIN 268 | IF (theValue IS NOT NULL) THEN 269 | RETURN TO_CHAR(theValue, 'FM999999999999990D099999999', 'NLS_NUMERIC_CHARACTERS = ''.,'''); 270 | ELSE 271 | RETURN ''; 272 | END IF; 273 | END asString; 274 | 275 | ---------------------------------------------------------- 276 | -- asString 277 | -- 278 | FUNCTION asString(theValue IN BOOLEAN) RETURN VARCHAR2 279 | IS 280 | BEGIN 281 | IF (theValue IS NOT NULL) THEN 282 | RETURN CASE theValue WHEN TRUE THEN 'TRUE' ELSE 'FALSE' END; 283 | ELSE 284 | RETURN ''; 285 | END IF; 286 | END asString; 287 | 288 | ---------------------------------------------------------- 289 | -- asString 290 | -- 291 | FUNCTION asString(theValue IN DATE) RETURN VARCHAR2 292 | IS 293 | BEGIN 294 | IF (theValue IS NOT NULL) THEN 295 | RETURN TO_CHAR(theValue, 'YYYY.MM.DD HH24:MI:SS'); 296 | ELSE 297 | RETURN ''; 298 | END IF; 299 | END asString; 300 | 301 | ---------------------------------------------------------- 302 | -- asStringLOB 303 | -- 304 | FUNCTION asStringLOB(theValue IN CLOB) RETURN VARCHAR2 305 | IS 306 | aSize INTEGER; 307 | aAmount INTEGER; 308 | aText VARCHAR2(32767); 309 | BEGIN 310 | IF (theValue IS NOT NULL) THEN 311 | aSize := dbms_lob.getlength(theValue); 312 | aText := 'length=('||aSize||')'; 313 | IF (aSize > 0) THEN 314 | aAmount := LEAST(aSize, 100); 315 | aText := aText||' value=('||dbms_lob.substr(theValue, aAmount)||')'; 316 | END IF; 317 | ELSE 318 | aText := ''; 319 | END IF; 320 | 321 | RETURN aText; 322 | END asStringLOB; 323 | 324 | ---------------------------------------------------------- 325 | -- asStringLOB 326 | -- 327 | FUNCTION asStringLOB(theValue IN BLOB) RETURN VARCHAR2 328 | IS 329 | aSize INTEGER; 330 | aAmount INTEGER; 331 | aRaw RAW(1000); 332 | aText VARCHAR2(32767); 333 | BEGIN 334 | IF (theValue IS NOT NULL) THEN 335 | aSize := dbms_lob.getlength(theValue); 336 | aText := 'length=('||aSize||')'; 337 | IF (aSize > 0) THEN 338 | aAmount := LEAST(aSize, 100); 339 | aText := aText||' value=('|| utl_raw.cast_to_varchar2(dbms_lob.substr(theValue, aAmount))||')'; 340 | END IF; 341 | ELSE 342 | aText := ''; 343 | END IF; 344 | 345 | RETURN aText; 346 | END asStringLOB; 347 | 348 | ---------------------------------------------------------- 349 | -- reportSuccess (private) 350 | -- 351 | PROCEDURE reportSuccess(theTitle IN VARCHAR2, theTest IN VARCHAR2, theExpected IN CLOB, theComputed IN CLOB) 352 | IS 353 | PRAGMA AUTONOMOUS_TRANSACTION; 354 | BEGIN 355 | INSERT INTO UT_test_table (ID, When, Module, Title, Success, Result, Expected, Computed) 356 | VALUES (UT_test_seq.NEXTVAL, SYSTIMESTAMP, NVL(CurrentModule, '-'), theTitle, 'Y', theTest, theExpected, theComputed); 357 | COMMIT; 358 | END reportSuccess; 359 | 360 | ---------------------------------------------------------- 361 | -- reportFailure (private) 362 | -- 363 | PROCEDURE reportFailure(theTitle IN VARCHAR2, theTest IN VARCHAR2, theExpected IN CLOB, theComputed IN CLOB) 364 | IS 365 | BEGIN 366 | INSERT INTO UT_test_table (ID, When, Module, Title, Success, Result, Expected, Computed) 367 | VALUES (UT_test_seq.NEXTVAL, SYSTIMESTAMP, NVL(CurrentModule, '-'), theTitle, 'N', theTest, theExpected, theComputed); 368 | COMMIT; 369 | END reportFailure; 370 | 371 | ---------------------------------------------------------- 372 | -- console (private) 373 | -- 374 | PROCEDURE console(theText IN VARCHAR2 DEFAULT NULL) 375 | IS 376 | BEGIN 377 | dbms_output.put_line(theText); 378 | EXCEPTION 379 | WHEN OTHERS THEN 380 | NULL; 381 | END console; 382 | 383 | 384 | END UT_util; 385 | / 386 | -------------------------------------------------------------------------------- /unittest/UT_util.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE UT_util IS 3 | 4 | ------------ 5 | -- OVERVIEW 6 | -- 7 | -- This package contains the framework for PL/SQL unit tests. 8 | -- 9 | 10 | ----------- 11 | -- EXAMPLE 12 | -- 13 | -- 14 | 15 | ------------- 16 | -- RESOURCES 17 | -- 18 | -- 19 | 20 | 21 | ---------------------------------------------------------- 22 | -- GLOBAL PUBLIC EXCEPTIONS 23 | ---------------------------------------------------------- 24 | 25 | 26 | ---------------------------------------------------------- 27 | -- GLOBAL PUBLIC TYPES 28 | ---------------------------------------------------------- 29 | 30 | 31 | ---------------------------------------------------------- 32 | -- GLOBAL PUBLIC CONSTANTS 33 | ---------------------------------------------------------- 34 | 35 | 36 | ---------------------------------------------------------- 37 | -- GLOBAL PUBLIC VARIABLES 38 | ---------------------------------------------------------- 39 | 40 | 41 | ---------------------------------------------------------- 42 | -- GLOBAL PUBLIC MODULES 43 | ---------------------------------------------------------- 44 | 45 | 46 | ---------------------------------------------------------- 47 | -- Identify the current test module 48 | -- 49 | PROCEDURE module(theModule IN VARCHAR2); 50 | 51 | ---------------------------------------------------------- 52 | -- Test for equality of VARCHAR2 53 | -- 54 | PROCEDURE eq( theTitle IN VARCHAR2, 55 | theExpected IN VARCHAR2, 56 | theComputed IN VARCHAR2, 57 | theNullOK IN BOOLEAN DEFAULT FALSE 58 | ); 59 | 60 | ---------------------------------------------------------- 61 | -- Test for equality of BOOLEAN 62 | -- 63 | PROCEDURE eq( theTitle IN VARCHAR2, 64 | theExpected IN BOOLEAN, 65 | theComputed IN BOOLEAN, 66 | theNullOK IN BOOLEAN DEFAULT FALSE 67 | ); 68 | 69 | ---------------------------------------------------------- 70 | -- Test for equality of NUMBER 71 | -- 72 | PROCEDURE eq( theTitle IN VARCHAR2, 73 | theExpected IN NUMBER, 74 | theComputed IN NUMBER, 75 | theNullOK IN BOOLEAN DEFAULT FALSE 76 | ); 77 | 78 | ---------------------------------------------------------- 79 | -- Test for equality of DATE 80 | -- 81 | PROCEDURE eq( theTitle IN VARCHAR2, 82 | theExpected IN DATE, 83 | theComputed IN DATE, 84 | theNullOK IN BOOLEAN DEFAULT FALSE 85 | ); 86 | 87 | ---------------------------------------------------------- 88 | -- Test for equality of CLOB 89 | -- We are using a different name to preventing problems 90 | -- when mixing with eVARCHAR2 signature. 91 | -- 92 | PROCEDURE eqLOB(theTitle IN VARCHAR2, 93 | theExpected IN CLOB, 94 | theComputed IN CLOB, 95 | theNullOK IN BOOLEAN DEFAULT FALSE 96 | ); 97 | 98 | ---------------------------------------------------------- 99 | -- Test for equality of BLOB 100 | -- We are using a different name to preventing problems 101 | -- when mixing with eVARCHAR2 signature. 102 | -- 103 | PROCEDURE eqLOB(theTitle IN VARCHAR2, 104 | theExpected IN BLOB, 105 | theComputed IN BLOB, 106 | theNullOK IN BOOLEAN DEFAULT FALSE 107 | ); 108 | 109 | ---------------------------------------------------------- 110 | -- Test if the condition is TRUE 111 | -- 112 | PROCEDURE ok( theTitle IN VARCHAR2, 113 | theValue IN BOOLEAN 114 | ); 115 | 116 | ---------------------------------------------------------- 117 | -- Test if the condition is FALSE 118 | -- 119 | PROCEDURE ko( theTitle IN VARCHAR2, 120 | theValue IN BOOLEAN 121 | ); 122 | 123 | --------------------------------------------------------- 124 | -- Convert to string 125 | -- 126 | FUNCTION asString(theValue IN VARCHAR2) RETURN VARCHAR2; 127 | 128 | ---------------------------------------------------------- 129 | -- Convert to string 130 | -- 131 | FUNCTION asString(theValue IN NUMBER) RETURN VARCHAR2; 132 | 133 | ---------------------------------------------------------- 134 | -- Convert to string 135 | -- 136 | FUNCTION asString(theValue IN BOOLEAN) RETURN VARCHAR2; 137 | 138 | ---------------------------------------------------------- 139 | -- Convert to string 140 | -- 141 | FUNCTION asString(theValue IN DATE) RETURN VARCHAR2; 142 | 143 | ---------------------------------------------------------- 144 | -- Convert a CLOB value to string 145 | -- We are using a different name to preventing problems 146 | -- when mixing with eVARCHAR2 signature. 147 | -- 148 | FUNCTION asStringLOB(theValue IN CLOB) RETURN VARCHAR2; 149 | 150 | ---------------------------------------------------------- 151 | -- Convert a BLOB value to string 152 | -- We are using a different name to preventing problems 153 | -- when mixing with eVARCHAR2 signature. 154 | -- 155 | FUNCTION asStringLOB(theValue IN BLOB) RETURN VARCHAR2; 156 | 157 | 158 | END UT_util; 159 | / 160 | -------------------------------------------------------------------------------- /unittest/json_sql_ut.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE BODY json_sql_UT IS 3 | 4 | ---------------------------------------------------------- 5 | -- PRIVATE TYPES 6 | ---------------------------------------------------------- 7 | 8 | ---------------------------------------------------------- 9 | -- PRIVATE CONSTANTS 10 | ---------------------------------------------------------- 11 | 12 | TODAY CONSTANT DATE := TRUNC(SYSDATE); 13 | 14 | ---------------------------------------------------------- 15 | -- LOCAL MODULES 16 | ---------------------------------------------------------- 17 | 18 | FUNCTION toJSON(theDate IN DATE) RETURN VARCHAR2; 19 | 20 | ---------------------------------------------------------- 21 | -- GLOBAL MODULES 22 | ---------------------------------------------------------- 23 | 24 | ---------------------------------------------------------- 25 | -- test a dynamic select statement returning objects (private) 26 | -- 27 | PROCEDURE UT_object 28 | IS 29 | ROW_1 CONSTANT VARCHAR2(2000) := '{"ID":1,"NAME":"john doe","BIRTHDAY":"'||toJSON(TODAY)||'"}'; 30 | ROW_2 CONSTANT VARCHAR2(2000) := '{"ID":2,"NAME":"robin williams","BIRTHDAY":"'||toJSON(TODAY+1)||'"}'; 31 | ROW_3 CONSTANT VARCHAR2(2000) := '{"ID":3,"NAME":"martin donovan","BIRTHDAY":"'||toJSON(TODAY+2)||'"}'; 32 | 33 | aSql VARCHAR2(2000); 34 | aBinding jsonObject := jsonObject(); 35 | aLob CLOB := empty_clob(); 36 | BEGIN 37 | UT_util.module('UT_object'); 38 | 39 | -- allocate clob 40 | dbms_lob.createtemporary(aLob, TRUE); 41 | 42 | -- select all rows 43 | aSql := 'SELECT * FROM temp_json_sql_ut ORDER BY id'; 44 | json_sql.get(sqlCmd=>aSql, format=>json_sql.FORMAT_OBJ).to_clob(theLobBuf=>aLob); 45 | UT_util.eqLOB( theTitle => aSql, 46 | theComputed => aLob, 47 | theExpected => TO_CLOB('{"rows":['||ROW_1||','||ROW_2||','||ROW_3||']}'), 48 | theNullOK => TRUE 49 | ); 50 | 51 | -- select one row 52 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = 2'; 53 | json_sql.get(sqlCmd=>aSql, format=>json_sql.FORMAT_OBJ).to_clob(theLobBuf=>aLob); 54 | UT_util.eqLOB( theTitle => aSql, 55 | theComputed => aLob, 56 | theExpected => TO_CLOB('{"rows":['||ROW_2||']}'), 57 | theNullOK => TRUE 58 | ); 59 | 60 | -- select one row using bind variables 61 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = :id'; 62 | aBinding.put('id', 3); 63 | json_sql.get(sqlCmd=>aSql, sqlBind=>aBinding, format=>json_sql.FORMAT_OBJ).to_clob(theLobBuf=>aLob); 64 | UT_util.eqLOB( theTitle => aSql, 65 | theComputed => aLob, 66 | theExpected => TO_CLOB('{"rows":['||ROW_3||']}'), 67 | theNullOK => TRUE 68 | ); 69 | 70 | -- select no row 71 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = 0'; 72 | json_sql.get(sqlCmd=>aSql, format=>json_sql.FORMAT_OBJ).to_clob(theLobBuf=>aLob); 73 | UT_util.eqLOB( theTitle => aSql, 74 | theComputed => aLob, 75 | theExpected => TO_CLOB('{"rows":[]}'), 76 | theNullOK => TRUE 77 | ); 78 | 79 | -- cleanup 80 | dbms_lob.freetemporary(aLob); 81 | END UT_object; 82 | 83 | ---------------------------------------------------------- 84 | -- test a dynamic select statement returning arrays (private) 85 | -- 86 | PROCEDURE UT_array 87 | IS 88 | COLS CONSTANT VARCHAR2(2000) := '"cols":["ID","NAME","BIRTHDAY"]'; 89 | ROW_1 CONSTANT VARCHAR2(2000) := '[1,"john doe","'||toJSON(TODAY)||'"]'; 90 | ROW_2 CONSTANT VARCHAR2(2000) := '[2,"robin williams","'||toJSON(TODAY+1)||'"]'; 91 | ROW_3 CONSTANT VARCHAR2(2000) := '[3,"martin donovan","'||toJSON(TODAY+2)||'"]'; 92 | 93 | aSql VARCHAR2(2000); 94 | aBinding jsonObject := jsonObject(); 95 | aLob CLOB := empty_clob(); 96 | BEGIN 97 | UT_util.module('UT_array'); 98 | 99 | -- allocate clob 100 | dbms_lob.createtemporary(aLob, TRUE); 101 | 102 | -- select all rows 103 | aSql := 'SELECT * FROM temp_json_sql_ut ORDER BY id'; 104 | json_sql.get(sqlCmd=>aSql).to_clob(theLobBuf=>aLob); 105 | UT_util.eqLOB( theTitle => aSql, 106 | theComputed => aLob, 107 | theExpected => TO_CLOB('{'||COLS||',"rows":['||ROW_1||','||ROW_2||','||ROW_3||']}'), 108 | theNullOK => TRUE 109 | ); 110 | 111 | -- select one row 112 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = 2'; 113 | json_sql.get(sqlCmd=>aSql).to_clob(theLobBuf=>aLob); 114 | UT_util.eqLOB( theTitle => aSql, 115 | theComputed => aLob, 116 | theExpected => TO_CLOB('{'||COLS||',"rows":['||ROW_2||']}'), 117 | theNullOK => TRUE 118 | ); 119 | 120 | -- select one row using bind variables 121 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = :id'; 122 | aBinding.put('id', 3); 123 | json_sql.get(sqlCmd=>aSql, sqlBind=>aBinding).to_clob(theLobBuf=>aLob); 124 | UT_util.eqLOB( theTitle => aSql, 125 | theComputed => aLob, 126 | theExpected => TO_CLOB('{'||COLS||',"rows":['||ROW_3||']}'), 127 | theNullOK => TRUE 128 | ); 129 | 130 | -- select no row 131 | aSql := 'SELECT * FROM temp_json_sql_ut WHERE id = 0'; 132 | json_sql.get(sqlCmd=>aSql).to_clob(theLobBuf=>aLob); 133 | UT_util.eqLOB( theTitle => aSql, 134 | theComputed => aLob, 135 | theExpected => TO_CLOB('{'||COLS||',"rows":[]}'), 136 | theNullOK => TRUE 137 | ); 138 | 139 | -- cleanup 140 | dbms_lob.freetemporary(aLob); 141 | END UT_array; 142 | 143 | ---------------------------------------------------------- 144 | -- toJSON (private) 145 | -- 146 | FUNCTION toJSON(theDate IN DATE) RETURN VARCHAR2 147 | IS 148 | BEGIN 149 | RETURN TO_CHAR(theDate, 'FXYYYY-MM-DD"T"HH24:MI:SS'); 150 | END toJSON; 151 | 152 | ---------------------------------------------------------- 153 | -- Run unit tests 154 | -- 155 | PROCEDURE run 156 | IS 157 | BEGIN 158 | UT_object; 159 | UT_array; 160 | END run; 161 | 162 | ---------------------------------------------------------- 163 | -- Prepare unit test 164 | -- 165 | PROCEDURE prepare 166 | IS 167 | BEGIN 168 | BEGIN 169 | EXECUTE IMMEDIATE 'DROP TABLE temp_json_sql_ut'; 170 | EXCEPTION 171 | WHEN OTHERS THEN 172 | NULL; 173 | END; 174 | EXECUTE IMMEDIATE 'CREATE TABLE temp_json_sql_ut (id NUMBER, name VARCHAR2(30), birthday DATE)'; 175 | EXECUTE IMMEDIATE 'INSERT INTO temp_json_sql_ut VALUES (:1, :2, :3)' USING 1, 'john doe', TODAY; 176 | EXECUTE IMMEDIATE 'INSERT INTO temp_json_sql_ut VALUES (:1, :2, :3)' USING 2, 'robin williams', TODAY + 1; 177 | EXECUTE IMMEDIATE 'INSERT INTO temp_json_sql_ut VALUES (:1, :2, :3)' USING 3, 'martin donovan', TODAY + 2; 178 | END prepare; 179 | 180 | ---------------------------------------------------------- 181 | -- Cleanup unit test 182 | -- 183 | PROCEDURE cleanup 184 | IS 185 | BEGIN 186 | EXECUTE IMMEDIATE 'DROP TABLE temp_json_sql_ut'; 187 | END cleanup; 188 | 189 | END json_sql_UT; 190 | / 191 | -------------------------------------------------------------------------------- /unittest/json_sql_ut.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_sql_UT IS 3 | 4 | ------------ 5 | -- OVERVIEW 6 | -- 7 | -- Unit tests for the PL/SQL JSON library dynamic SQL interface 8 | -- 9 | -- 10 | 11 | ----------- 12 | -- EXAMPLE 13 | -- 14 | -- 15 | 16 | ------------- 17 | -- RESOURCES 18 | -- 19 | -- 20 | 21 | ---------------------------------------------------------- 22 | -- GLOBAL PUBLIC TYPES 23 | ---------------------------------------------------------- 24 | 25 | ---------------------------------------------------------- 26 | -- GLOBAL PUBLIC CONSTANTS 27 | ---------------------------------------------------------- 28 | 29 | ---------------------------------------------------------- 30 | -- GLOBAL PUBLIC VARIABLES 31 | ---------------------------------------------------------- 32 | 33 | ---------------------------------------------------------- 34 | -- GLOBAL PUBLIC MODULES 35 | ---------------------------------------------------------- 36 | 37 | ---------------------------------------------------------- 38 | -- Run unit tests 39 | -- 40 | PROCEDURE prepare; 41 | PROCEDURE run; 42 | PROCEDURE cleanup; 43 | 44 | END json_sql_UT; 45 | / 46 | -------------------------------------------------------------------------------- /unittest/json_ut.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE json_UT IS 3 | 4 | ------------ 5 | -- OVERVIEW 6 | -- 7 | -- Unit tests for the PL/SQL JSON library 8 | -- 9 | -- 10 | 11 | ----------- 12 | -- EXAMPLE 13 | -- 14 | -- 15 | 16 | ------------- 17 | -- RESOURCES 18 | -- 19 | -- 20 | 21 | ---------------------------------------------------------- 22 | -- GLOBAL PUBLIC TYPES 23 | ---------------------------------------------------------- 24 | 25 | ---------------------------------------------------------- 26 | -- GLOBAL PUBLIC CONSTANTS 27 | ---------------------------------------------------------- 28 | 29 | ---------------------------------------------------------- 30 | -- GLOBAL PUBLIC VARIABLES 31 | ---------------------------------------------------------- 32 | 33 | ---------------------------------------------------------- 34 | -- GLOBAL PUBLIC MODULES 35 | ---------------------------------------------------------- 36 | 37 | ---------------------------------------------------------- 38 | -- Run unit tests 39 | -- 40 | PROCEDURE prepare; 41 | PROCEDURE run; 42 | PROCEDURE cleanup; 43 | 44 | END json_UT; 45 | / 46 | -------------------------------------------------------------------------------- /unittest/unittest.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * 3 | * NAME 4 | * unittest.sql 5 | * 6 | * AUTHOR 7 | * Dieter Oberkofler 8 | * 9 | * FUNCTION 10 | * Install and run the unit tests for the plsql_json module 11 | * 12 | */ 13 | 14 | 15 | -- environment 16 | set pagesize 10000 linesize 10000 trimout on trimspool on 17 | 18 | -- delete existing objects 19 | whenever sqlerror continue 20 | DROP TABLE UT_test_table; 21 | DROP SEQUENCE UT_test_seq; 22 | whenever sqlerror exit 1 23 | 24 | -- install objects 25 | CREATE TABLE UT_test_table 26 | ( 27 | ID NUMBER NOT NULL, -- test id 28 | When TIMESTAMP NOT NULL, -- timestamp 29 | Module VARCHAR2(2000) NOT NULL, -- module name 30 | Title CLOB NOT NULL, -- test name 31 | Success CHAR(1) NOT NULL -- was test successful (1=yes, 0=no) 32 | CHECK(Success IN ('Y', 'N')), 33 | Result CLOB, 34 | Expected CLOB, 35 | Computed CLOB 36 | ); 37 | CREATE SEQUENCE UT_test_seq START WITH 1; 38 | 39 | -- install the json debug package 40 | @@../json_debug.pks 41 | @@../json_debug.pkb 42 | 43 | -- install the unit test framework 44 | @@UT_util.pks 45 | show errors 46 | @@UT_util.pkb 47 | show errors 48 | 49 | -- load the unit tests 50 | @@json_ut.pks 51 | show errors 52 | @@json_ut.pkb 53 | show errors 54 | @@json_sql_ut.pks 55 | show errors 56 | @@json_sql_ut.pkb 57 | show errors 58 | 59 | -- run the unit tests 60 | BEGIN 61 | json_ut.prepare; 62 | json_ut.run; 63 | json_ut.cleanup; 64 | 65 | json_sql_ut.prepare; 66 | json_sql_ut.run; 67 | json_sql_ut.cleanup; 68 | END; 69 | / 70 | 71 | -- show the results 72 | SELECT 'Successful unit tests: '||C "Unit test results" FROM (SELECT COUNT(*) C FROM plsql_json.UT_test_table WHERE Success = 'Y') 73 | UNION 74 | SELECT 'Failed unit tests: '||C "Unit test results" FROM (SELECT COUNT(*) C FROM plsql_json.UT_test_table WHERE Success = 'N') 75 | ORDER BY 1 DESC; 76 | 77 | -- show the errors 78 | column Module format a30 79 | column Title format a30 80 | column Result format a30 81 | column Expected format a30 82 | column Computed format a30 83 | SELECT ID, Module, Title, Result, Expected, Computed 84 | FROM UT_test_table 85 | WHERE Success = 'N' 86 | ORDER BY ID; 87 | 88 | -- cleanup 89 | whenever sqlerror continue 90 | DROP TABLE UT_test_table; 91 | DROP SEQUENCE UT_test_seq; 92 | DROP PACKAGE json_ut; 93 | DROP PACKAGE json_sql_ut; 94 | DROP PACKAGE UT_util; 95 | whenever sqlerror exit 1 96 | -------------------------------------------------------------------------------- /user.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * 3 | * NAME 4 | * user.sql 5 | * 6 | * AUTHOR 7 | * Dieter Oberkofler 8 | * 9 | * FUNCTION 10 | * Create a sample "plsql_json" schema 11 | * 12 | * NOTES 13 | * 14 | */ 15 | 16 | 17 | CREATE USER plsql_json IDENTIFIED BY plsql_json; 18 | GRANT create session TO plsql_json; 19 | GRANT unlimited tablespace TO plsql_json; 20 | GRANT create table TO plsql_json; 21 | GRANT create view TO plsql_json; 22 | GRANT create sequence TO plsql_json; 23 | GRANT create procedure TO plsql_json; 24 | GRANT create trigger TO plsql_json; 25 | GRANT create type TO plsql_json; 26 | GRANT execute on dbms_lob TO plsql_json; 27 | GRANT execute on dbms_output TO plsql_json; 28 | --------------------------------------------------------------------------------