drh | 5fa5c10 | 2015-08-12 16:49:40 +0000 | [diff] [blame] | 1 | # 2015-08-12 |
| 2 | # |
| 3 | # The author disclaims copyright to this source code. In place of |
| 4 | # a legal notice, here is a blessing: |
| 5 | # |
| 6 | # May you do good and not evil. |
| 7 | # May you find forgiveness for yourself and forgive others. |
| 8 | # May you share freely, never taking more than you give. |
| 9 | # |
| 10 | #*********************************************************************** |
| 11 | # This file implements tests for JSON SQL functions extension to the |
| 12 | # SQLite library. |
| 13 | # |
| 14 | |
| 15 | set testdir [file dirname $argv0] |
| 16 | source $testdir/tester.tcl |
| 17 | |
| 18 | load_static_extension db json |
drh | f5ddb9c | 2015-09-11 00:06:41 +0000 | [diff] [blame] | 19 | do_execsql_test json1-1.1.00 { |
drh | 5fa5c10 | 2015-08-12 16:49:40 +0000 | [diff] [blame] | 20 | SELECT json_array(1,2.5,null,'hello'); |
| 21 | } {[1,2.5,null,"hello"]} |
drh | f5ddb9c | 2015-09-11 00:06:41 +0000 | [diff] [blame] | 22 | do_execsql_test json1-1.1.01 { |
| 23 | SELECT json_array(1,'{"abc":2.5,"def":null,"ghi":hello}',99); |
| 24 | -- the second term goes in as a string: |
| 25 | } {[1,"{\\"abc\\":2.5,\\"def\\":null,\\"ghi\\":hello}",99]} |
| 26 | do_execsql_test json1-1.1.02 { |
| 27 | SELECT json_array(1,json('{"abc":2.5,"def":null,"ghi":"hello"}'),99); |
| 28 | -- the second term goes in as JSON |
| 29 | } {[1,{"abc":2.5,"def":null,"ghi":"hello"},99]} |
| 30 | do_execsql_test json1-1.1.03 { |
| 31 | SELECT json_array(1,json_object('abc',2.5,'def',null,'ghi','hello'),99); |
| 32 | -- the second term goes in as JSON |
| 33 | } {[1,{"abc":2.5,"def":null,"ghi":"hello"},99]} |
drh | 5fa5c10 | 2015-08-12 16:49:40 +0000 | [diff] [blame] | 34 | do_execsql_test json1-1.2 { |
| 35 | SELECT hex(json_array('String "\ Test')); |
| 36 | } {5B22537472696E67205C225C5C2054657374225D} |
| 37 | do_catchsql_test json1-1.3 { |
drh | dc38495 | 2015-09-19 18:54:39 +0000 | [diff] [blame^] | 38 | SELECT json_array(1,printf('%.1000c','x'),x'abcd',3); |
drh | 5fa5c10 | 2015-08-12 16:49:40 +0000 | [diff] [blame] | 39 | } {1 {JSON cannot hold BLOB values}} |
| 40 | do_execsql_test json1-1.4 { |
| 41 | SELECT json_array(-9223372036854775808,9223372036854775807,0,1,-1, |
| 42 | 0.0, 1.0, -1.0, -1e99, +2e100, |
| 43 | 'one','two','three', |
| 44 | 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, |
| 45 | 19, NULL, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, |
| 46 | 'abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ', |
| 47 | 'abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ', |
| 48 | 'abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ', |
| 49 | 99); |
| 50 | } {[-9223372036854775808,9223372036854775807,0,1,-1,0.0,1.0,-1.0,-1.0e+99,2.0e+100,"one","two","three",4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,null,21,22,23,24,25,26,27,28,29,30,31,"abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ","abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ","abcdefghijklmnopqrstuvwyxzABCDEFGHIJKLMNOPQRSTUVWXYZ",99]} |
| 51 | |
drh | 2032d60 | 2015-08-12 17:23:34 +0000 | [diff] [blame] | 52 | do_execsql_test json1-2.1 { |
| 53 | SELECT json_object('a',1,'b',2.5,'c',null,'d','String Test'); |
| 54 | } {{{"a":1,"b":2.5,"c":null,"d":"String Test"}}} |
| 55 | do_catchsql_test json1-2.2 { |
drh | dc38495 | 2015-09-19 18:54:39 +0000 | [diff] [blame^] | 56 | SELECT json_object('a',printf('%.1000c','x'),2,2.5); |
drh | 2032d60 | 2015-08-12 17:23:34 +0000 | [diff] [blame] | 57 | } {1 {json_object() labels must be TEXT}} |
| 58 | do_catchsql_test json1-2.3 { |
| 59 | SELECT json_object('a',1,'b'); |
| 60 | } {1 {json_object() requires an even number of arguments}} |
| 61 | do_catchsql_test json1-2.4 { |
drh | dc38495 | 2015-09-19 18:54:39 +0000 | [diff] [blame^] | 62 | SELECT json_object('a',printf('%.1000c','x'),'b',x'abcd'); |
drh | 2032d60 | 2015-08-12 17:23:34 +0000 | [diff] [blame] | 63 | } {1 {JSON cannot hold BLOB values}} |
| 64 | |
drh | ecb5fed | 2015-08-28 03:33:50 +0000 | [diff] [blame] | 65 | do_execsql_test json1-3.1 { |
| 66 | SELECT json_replace('{"a":1,"b":2}','$.a','[3,4,5]'); |
| 67 | } {{{"a":"[3,4,5]","b":2}}} |
| 68 | do_execsql_test json1-3.2 { |
drh | f5ddb9c | 2015-09-11 00:06:41 +0000 | [diff] [blame] | 69 | SELECT json_replace('{"a":1,"b":2}','$.a',json('[3,4,5]')); |
drh | ecb5fed | 2015-08-28 03:33:50 +0000 | [diff] [blame] | 70 | } {{{"a":[3,4,5],"b":2}}} |
| 71 | do_execsql_test json1-3.3 { |
| 72 | SELECT json_type(json_set('{"a":1,"b":2}','$.b','{"x":3,"y":4}'),'$.b'); |
| 73 | } {text} |
| 74 | do_execsql_test json1-3.4 { |
drh | f5ddb9c | 2015-09-11 00:06:41 +0000 | [diff] [blame] | 75 | SELECT json_type(json_set('{"a":1,"b":2}','$.b',json('{"x":3,"y":4}')),'$.b'); |
drh | ecb5fed | 2015-08-28 03:33:50 +0000 | [diff] [blame] | 76 | } {object} |
drh | 2032d60 | 2015-08-12 17:23:34 +0000 | [diff] [blame] | 77 | |
drh | d1f0068 | 2015-08-29 16:02:37 +0000 | [diff] [blame] | 78 | # Per rfc7159, any JSON value is allowed at the top level, and whitespace |
| 79 | # is permitting before and/or after that value. |
| 80 | # |
| 81 | do_execsql_test json1-4.1 { |
| 82 | CREATE TABLE j1(x); |
| 83 | INSERT INTO j1(x) |
| 84 | VALUES('true'),('false'),('null'),('123'),('-234'),('34.5e+6'), |
| 85 | ('""'),('"\""'),('"\\"'),('"abcdefghijlmnopqrstuvwxyz"'), |
| 86 | ('[]'),('{}'),('[true,false,null,123,-234,34.5e+6,{},[]]'), |
| 87 | ('{"a":true,"b":{"c":false}}'); |
| 88 | SELECT * FROM j1 WHERE NOT json_valid(x); |
| 89 | } {} |
| 90 | do_execsql_test json1-4.2 { |
| 91 | SELECT * FROM j1 WHERE NOT json_valid(char(0x20,0x09,0x0a,0x0d)||x); |
| 92 | } {} |
| 93 | do_execsql_test json1-4.3 { |
| 94 | SELECT * FROM j1 WHERE NOT json_valid(x||char(0x20,0x09,0x0a,0x0d)); |
| 95 | } {} |
| 96 | |
| 97 | # But an empty string, or a string of pure whitespace is not valid JSON. |
| 98 | # |
| 99 | do_execsql_test json1-4.4 { |
| 100 | SELECT json_valid(''), json_valid(char(0x20,0x09,0x0a,0x0d)); |
| 101 | } {0 0} |
| 102 | |
| 103 | # json_remove() and similar functions with no edit operations return their |
| 104 | # input unchanged. |
| 105 | # |
| 106 | do_execsql_test json1-4.5 { |
| 107 | SELECT x FROM j1 WHERE json_remove(x)<>x; |
| 108 | } {} |
| 109 | do_execsql_test json1-4.6 { |
| 110 | SELECT x FROM j1 WHERE json_replace(x)<>x; |
| 111 | } {} |
| 112 | do_execsql_test json1-4.7 { |
| 113 | SELECT x FROM j1 WHERE json_set(x)<>x; |
| 114 | } {} |
| 115 | do_execsql_test json1-4.8 { |
| 116 | SELECT x FROM j1 WHERE json_insert(x)<>x; |
| 117 | } {} |
| 118 | |
| 119 | # json_extract(JSON,'$') will return objects and arrays without change. |
| 120 | # |
| 121 | do_execsql_test json-4.10 { |
| 122 | SELECT count(*) FROM j1 WHERE json_type(x) IN ('object','array'); |
| 123 | SELECT x FROM j1 |
| 124 | WHERE json_extract(x,'$')<>x |
| 125 | AND json_type(x) IN ('object','array'); |
| 126 | } {4} |
| 127 | |
drh | 20b3b61 | 2015-08-29 18:30:30 +0000 | [diff] [blame] | 128 | do_execsql_test json-5.1 { |
| 129 | CREATE TABLE j2(id INTEGER PRIMARY KEY, json, src); |
| 130 | INSERT INTO j2(id,json,src) |
| 131 | VALUES(1,'{ |
| 132 | "firstName": "John", |
| 133 | "lastName": "Smith", |
| 134 | "isAlive": true, |
| 135 | "age": 25, |
| 136 | "address": { |
| 137 | "streetAddress": "21 2nd Street", |
| 138 | "city": "New York", |
| 139 | "state": "NY", |
| 140 | "postalCode": "10021-3100" |
| 141 | }, |
| 142 | "phoneNumbers": [ |
| 143 | { |
| 144 | "type": "home", |
| 145 | "number": "212 555-1234" |
| 146 | }, |
| 147 | { |
| 148 | "type": "office", |
| 149 | "number": "646 555-4567" |
| 150 | } |
| 151 | ], |
| 152 | "children": [], |
| 153 | "spouse": null |
| 154 | }','https://en.wikipedia.org/wiki/JSON'); |
| 155 | INSERT INTO j2(id,json,src) |
| 156 | VALUES(2, '{ |
| 157 | "id": "0001", |
| 158 | "type": "donut", |
| 159 | "name": "Cake", |
| 160 | "ppu": 0.55, |
| 161 | "batters": |
| 162 | { |
| 163 | "batter": |
| 164 | [ |
| 165 | { "id": "1001", "type": "Regular" }, |
| 166 | { "id": "1002", "type": "Chocolate" }, |
| 167 | { "id": "1003", "type": "Blueberry" }, |
| 168 | { "id": "1004", "type": "Devil''s Food" } |
| 169 | ] |
| 170 | }, |
| 171 | "topping": |
| 172 | [ |
| 173 | { "id": "5001", "type": "None" }, |
| 174 | { "id": "5002", "type": "Glazed" }, |
| 175 | { "id": "5005", "type": "Sugar" }, |
| 176 | { "id": "5007", "type": "Powdered Sugar" }, |
| 177 | { "id": "5006", "type": "Chocolate with Sprinkles" }, |
| 178 | { "id": "5003", "type": "Chocolate" }, |
| 179 | { "id": "5004", "type": "Maple" } |
| 180 | ] |
| 181 | }','https://adobe.github.io/Spry/samples/data_region/JSONDataSetSample.html'); |
| 182 | INSERT INTO j2(id,json,src) |
| 183 | VALUES(3,'[ |
| 184 | { |
| 185 | "id": "0001", |
| 186 | "type": "donut", |
| 187 | "name": "Cake", |
| 188 | "ppu": 0.55, |
| 189 | "batters": |
| 190 | { |
| 191 | "batter": |
| 192 | [ |
| 193 | { "id": "1001", "type": "Regular" }, |
| 194 | { "id": "1002", "type": "Chocolate" }, |
| 195 | { "id": "1003", "type": "Blueberry" }, |
| 196 | { "id": "1004", "type": "Devil''s Food" } |
| 197 | ] |
| 198 | }, |
| 199 | "topping": |
| 200 | [ |
| 201 | { "id": "5001", "type": "None" }, |
| 202 | { "id": "5002", "type": "Glazed" }, |
| 203 | { "id": "5005", "type": "Sugar" }, |
| 204 | { "id": "5007", "type": "Powdered Sugar" }, |
| 205 | { "id": "5006", "type": "Chocolate with Sprinkles" }, |
| 206 | { "id": "5003", "type": "Chocolate" }, |
| 207 | { "id": "5004", "type": "Maple" } |
| 208 | ] |
| 209 | }, |
| 210 | { |
| 211 | "id": "0002", |
| 212 | "type": "donut", |
| 213 | "name": "Raised", |
| 214 | "ppu": 0.55, |
| 215 | "batters": |
| 216 | { |
| 217 | "batter": |
| 218 | [ |
| 219 | { "id": "1001", "type": "Regular" } |
| 220 | ] |
| 221 | }, |
| 222 | "topping": |
| 223 | [ |
| 224 | { "id": "5001", "type": "None" }, |
| 225 | { "id": "5002", "type": "Glazed" }, |
| 226 | { "id": "5005", "type": "Sugar" }, |
| 227 | { "id": "5003", "type": "Chocolate" }, |
| 228 | { "id": "5004", "type": "Maple" } |
| 229 | ] |
| 230 | }, |
| 231 | { |
| 232 | "id": "0003", |
| 233 | "type": "donut", |
| 234 | "name": "Old Fashioned", |
| 235 | "ppu": 0.55, |
| 236 | "batters": |
| 237 | { |
| 238 | "batter": |
| 239 | [ |
| 240 | { "id": "1001", "type": "Regular" }, |
| 241 | { "id": "1002", "type": "Chocolate" } |
| 242 | ] |
| 243 | }, |
| 244 | "topping": |
| 245 | [ |
| 246 | { "id": "5001", "type": "None" }, |
| 247 | { "id": "5002", "type": "Glazed" }, |
| 248 | { "id": "5003", "type": "Chocolate" }, |
| 249 | { "id": "5004", "type": "Maple" } |
| 250 | ] |
| 251 | } |
| 252 | ]','https://adobe.github.io/Spry/samples/data_region/JSONDataSetSample.html'); |
| 253 | SELECT count(*) FROM j2; |
| 254 | } {3} |
| 255 | |
| 256 | do_execsql_test json-5.2 { |
| 257 | SELECT id, json_valid(json), json_type(json), '|' FROM j2 ORDER BY id; |
| 258 | } {1 1 object | 2 1 object | 3 1 array |} |
| 259 | |
| 260 | ifcapable !vtab { |
| 261 | finish_test |
| 262 | return |
| 263 | } |
| 264 | |
| 265 | # fullkey is always the same as path+key (with appropriate formatting) |
| 266 | # |
| 267 | do_execsql_test json-5.3 { |
| 268 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 269 | FROM j2, json_tree(j2.json) AS jx |
| 270 | WHERE fullkey!=(path || CASE WHEN typeof(key)=='integer' THEN '['||key||']' |
| 271 | ELSE '.'||key END); |
| 272 | } {} |
| 273 | do_execsql_test json-5.4 { |
| 274 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 275 | FROM j2, json_each(j2.json) AS jx |
| 276 | WHERE fullkey!=(path || CASE WHEN typeof(key)=='integer' THEN '['||key||']' |
| 277 | ELSE '.'||key END); |
| 278 | } {} |
| 279 | |
| 280 | |
| 281 | # Verify that the json_each.json and json_tree.json output is always the |
| 282 | # same as input. |
| 283 | # |
| 284 | do_execsql_test json-5.5 { |
| 285 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 286 | FROM j2, json_each(j2.json) AS jx |
| 287 | WHERE jx.json<>j2.json; |
| 288 | } {} |
| 289 | do_execsql_test json-5.6 { |
| 290 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 291 | FROM j2, json_tree(j2.json) AS jx |
| 292 | WHERE jx.json<>j2.json; |
| 293 | } {} |
| 294 | do_execsql_test json-5.7 { |
| 295 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 296 | FROM j2, json_each(j2.json) AS jx |
| 297 | WHERE jx.value<>jx.atom AND type NOT IN ('array','object'); |
| 298 | } {} |
| 299 | do_execsql_test json-5.8 { |
| 300 | SELECT j2.rowid, jx.rowid, fullkey, path, key |
| 301 | FROM j2, json_tree(j2.json) AS jx |
| 302 | WHERE jx.value<>jx.atom AND type NOT IN ('array','object'); |
| 303 | } {} |
| 304 | |
| 305 | |
| 306 | |
drh | 5fa5c10 | 2015-08-12 16:49:40 +0000 | [diff] [blame] | 307 | finish_test |