xref: /sqlite-3.40.0/test/json102.test (revision a4e4e184)
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# This file contains tests automatically generated from the json1
15# documentation.
16#
17
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21ifcapable !json1 {
22  finish_test
23  return
24}
25
26do_execsql_test json102-100 {
27  SELECT json_object('ex','[52,3.14159]');
28} {{{"ex":"[52,3.14159]"}}}
29do_execsql_test json102-110 {
30  SELECT json_object('ex',json('[52,3.14159]'));
31} {{{"ex":[52,3.14159]}}}
32do_execsql_test json102-120 {
33  SELECT json_object('ex',json_array(52,3.14159));
34} {{{"ex":[52,3.14159]}}}
35do_execsql_test json102-130 {
36  SELECT json(' { "this" : "is", "a": [ "test" ] } ');
37} {{{"this":"is","a":["test"]}}}
38do_execsql_test json102-140 {
39  SELECT json_array(1,2,'3',4);
40} {{[1,2,"3",4]}}
41do_execsql_test json102-150 {
42  SELECT json_array('[1,2]');
43} {{["[1,2]"]}}
44do_execsql_test json102-160 {
45  SELECT json_array(json_array(1,2));
46} {{[[1,2]]}}
47do_execsql_test json102-170 {
48  SELECT json_array(1,null,'3','[4,5]','{"six":7.7}');
49} {{[1,null,"3","[4,5]","{\"six\":7.7}"]}}
50do_execsql_test json102-180 {
51  SELECT json_array(1,null,'3',json('[4,5]'),json('{"six":7.7}'));
52} {{[1,null,"3",[4,5],{"six":7.7}]}}
53do_execsql_test json102-190 {
54  SELECT json_array_length('[1,2,3,4]');
55} {{4}}
56do_execsql_test json102-200 {
57  SELECT json_array_length('[1,2,3,4]', '$');
58} {{4}}
59do_execsql_test json102-210 {
60  SELECT json_array_length('[1,2,3,4]', '$[2]');
61} {{0}}
62do_execsql_test json102-220 {
63  SELECT json_array_length('{"one":[1,2,3]}');
64} {{0}}
65do_execsql_test json102-230 {
66  SELECT json_array_length('{"one":[1,2,3]}', '$.one');
67} {{3}}
68do_execsql_test json102-240 {
69  SELECT json_array_length('{"one":[1,2,3]}', '$.two');
70} {{}}
71do_execsql_test json102-250 {
72  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$');
73} {{{"a":2,"c":[4,5,{"f":7}]}}}
74do_execsql_test json102-251 {
75  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> '$';
76} {{{"a":2,"c":[4,5,{"f":7}]}}}
77do_execsql_test json102-260 {
78  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c');
79} {{[4,5,{"f":7}]}}
80do_execsql_test json102-261 {
81  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> '$.c';
82} {{[4,5,{"f":7}]}}
83do_execsql_test json102-262 {
84  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> 'c';
85} {{[4,5,{"f":7}]}}
86do_execsql_test json102-270 {
87  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c[2]');
88} {{{"f":7}}}
89do_execsql_test json102-271 {
90  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> '$.c[2]';
91} {{{"f":7}}}
92do_execsql_test json102-272 {
93  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> 'c' -> 2;
94} {{{"f":7}}}
95do_execsql_test json102-280 {
96  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c[2].f');
97} {{7}}
98do_execsql_test json102-281 {
99  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> 'c' -> 2 -> 'f';
100} {{7}}
101do_execsql_test json102-282 {
102  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> 'c' -> '[2]' -> 'f';
103} {{7}}
104do_execsql_test json102-290 {
105  SELECT json_extract('{"a":2,"c":[4,5],"f":7}','$.c','$.a');
106} {{[[4,5],2]}}
107do_execsql_test json102-300 {
108  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.x');
109} {{}}
110do_execsql_test json102-301 {
111  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> 'x';
112} {{}}
113do_execsql_test json102-302 {
114  SELECT '{"a":2,"c":[4,5,{"f":7}]}' -> NULL;
115} {{}}
116do_execsql_test json102-310 {
117  SELECT json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.x', '$.a');
118} {{[null,2]}}
119do_execsql_test json102-320 {
120  SELECT json_insert('{"a":2,"c":4}', '$.a', 99);
121} {{{"a":2,"c":4}}}
122do_execsql_test json102-330 {
123  SELECT json_insert('{"a":2,"c":4}', '$.e', 99);
124} {{{"a":2,"c":4,"e":99}}}
125do_execsql_test json102-340 {
126  SELECT json_replace('{"a":2,"c":4}', '$.a', 99);
127} {{{"a":99,"c":4}}}
128do_execsql_test json102-350 {
129  SELECT json_replace('{"a":2,"c":4}', '$.e', 99);
130} {{{"a":2,"c":4}}}
131do_execsql_test json102-360 {
132  SELECT json_set('{"a":2,"c":4}', '$.a', 99);
133} {{{"a":99,"c":4}}}
134do_execsql_test json102-370 {
135  SELECT json_set('{"a":2,"c":4}', '$.e', 99);
136} {{{"a":2,"c":4,"e":99}}}
137do_execsql_test json102-380 {
138  SELECT json_set('{"a":2,"c":4}', '$.c', '[97,96]');
139} {{{"a":2,"c":"[97,96]"}}}
140do_execsql_test json102-390 {
141  SELECT json_set('{"a":2,"c":4}', '$.c', json('[97,96]'));
142} {{{"a":2,"c":[97,96]}}}
143do_execsql_test json102-400 {
144  SELECT json_set('{"a":2,"c":4}', '$.c', json_array(97,96));
145} {{{"a":2,"c":[97,96]}}}
146do_execsql_test json102-410 {
147  SELECT json_object('a',2,'c',4);
148} {{{"a":2,"c":4}}}
149do_execsql_test json102-420 {
150  SELECT json_object('a',2,'c','{e:5}');
151} {{{"a":2,"c":"{e:5}"}}}
152do_execsql_test json102-430 {
153  SELECT json_object('a',2,'c',json_object('e',5));
154} {{{"a":2,"c":{"e":5}}}}
155do_execsql_test json102-440 {
156  SELECT json_remove('[0,1,2,3,4]','$[2]');
157} {{[0,1,3,4]}}
158do_execsql_test json102-450 {
159  SELECT json_remove('[0,1,2,3,4]','$[2]','$[0]');
160} {{[1,3,4]}}
161do_execsql_test json102-460 {
162  SELECT json_remove('[0,1,2,3,4]','$[0]','$[2]');
163} {{[1,2,4]}}
164do_execsql_test json102-470 {
165  SELECT json_remove('{"x":25,"y":42}');
166} {{{"x":25,"y":42}}}
167do_execsql_test json102-480 {
168  SELECT json_remove('{"x":25,"y":42}','$.z');
169} {{{"x":25,"y":42}}}
170do_execsql_test json102-490 {
171  SELECT json_remove('{"x":25,"y":42}','$.y');
172} {{{"x":25}}}
173do_execsql_test json102-500 {
174  SELECT json_remove('{"x":25,"y":42}','$');
175} {{}}
176do_execsql_test json102-510 {
177  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}');
178} {{object}}
179do_execsql_test json102-511 {
180  SELECT json_ntype('{"a":[2,3.5,true,false,null,"x"]}');
181} {{object}}
182do_execsql_test json102-520 {
183  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$');
184} {{object}}
185do_execsql_test json102-530 {
186  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a');
187} {{array}}
188do_execsql_test json102-540 {
189  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[0]');
190} {{integer}}
191do_execsql_test json102-550 {
192  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[1]');
193} {{real}}
194do_execsql_test json102-560 {
195  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[2]');
196} {{true}}
197do_execsql_test json102-570 {
198  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[3]');
199} {{false}}
200do_execsql_test json102-580 {
201  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[4]');
202} {{null}}
203do_execsql_test json102-590 {
204  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[5]');
205} {{text}}
206do_execsql_test json102-600 {
207  SELECT json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[6]');
208} {{}}
209do_execsql_test json102-610 {
210  SELECT json_valid(char(123)||'"x":35'||char(125));
211} {{1}}
212do_execsql_test json102-620 {
213  SELECT json_valid(char(123)||'"x":35');
214} {{0}}
215do_catchsql_test json102-630 {
216  SELECT json_type('["a",');
217} {1 {malformed JSON}}
218do_catchsql_test json102-631 {
219  SELECT json_ntype('["a",');
220} {0 {{}}}
221
222ifcapable vtab {
223do_execsql_test json102-1000 {
224  CREATE TABLE user(name,phone);
225  INSERT INTO user(name,phone) VALUES
226     ('Alice','["919-555-2345","804-555-3621"]'),
227     ('Bob','["201-555-8872"]'),
228     ('Cindy','["704-555-9983"]'),
229     ('Dave','["336-555-8421","704-555-4321","803-911-4421"]');
230  SELECT DISTINCT user.name
231    FROM user, json_each(user.phone)
232   WHERE json_each.value LIKE '704-%'
233   ORDER BY 1;
234} {Cindy Dave}
235
236do_execsql_test json102-1010 {
237  UPDATE user
238     SET phone=json_extract(phone,'$[0]')
239   WHERE json_array_length(phone)<2;
240  SELECT name, substr(phone,1,5) FROM user ORDER BY name;
241} {Alice {["919} Bob 201-5 Cindy 704-5 Dave {["336}}
242do_execsql_test json102-1011 {
243  SELECT name FROM user WHERE phone LIKE '704-%'
244  UNION
245  SELECT user.name
246    FROM user, json_each(user.phone)
247   WHERE json_valid(user.phone)
248     AND json_each.value LIKE '704-%';
249} {Cindy Dave}
250
251do_execsql_test json102-1100 {
252  CREATE TABLE big(json JSON);
253  INSERT INTO big(json) VALUES('{
254    "id":123,
255    "stuff":[1,2,3,4],
256    "partlist":[
257       {"uuid":"bb108722-572e-11e5-9320-7f3b63a4ca74"},
258       {"uuid":"c690dc14-572e-11e5-95f9-dfc8861fd535"},
259       {"subassembly":[
260          {"uuid":"6fa5181e-5721-11e5-a04e-57f3d7b32808"}
261       ]}
262    ]
263  }');
264  INSERT INTO big(json) VALUES('{
265    "id":456,
266    "stuff":["hello","world","xyzzy"],
267    "partlist":[
268       {"uuid":false},
269       {"uuid":"c690dc14-572e-11e5-95f9-dfc8861fd535"}
270    ]
271  }');
272} {}
273set correct_answer [list \
274    1 {$.id} 123 \
275    1 {$.stuff[0]} 1 \
276    1 {$.stuff[1]} 2 \
277    1 {$.stuff[2]} 3 \
278    1 {$.stuff[3]} 4 \
279    1 {$.partlist[0].uuid} bb108722-572e-11e5-9320-7f3b63a4ca74 \
280    1 {$.partlist[1].uuid} c690dc14-572e-11e5-95f9-dfc8861fd535 \
281    1 {$.partlist[2].subassembly[0].uuid} 6fa5181e-5721-11e5-a04e-57f3d7b32808 \
282    2 {$.id} 456 \
283    2 {$.stuff[0]} hello \
284    2 {$.stuff[1]} world \
285    2 {$.stuff[2]} xyzzy \
286    2 {$.partlist[0].uuid} 0 \
287    2 {$.partlist[1].uuid} c690dc14-572e-11e5-95f9-dfc8861fd535]
288do_execsql_test json102-1110 {
289  SELECT big.rowid, fullkey, value
290    FROM big, json_tree(big.json)
291   WHERE json_tree.type NOT IN ('object','array')
292   ORDER BY +big.rowid, +json_tree.id
293} $correct_answer
294do_execsql_test json102-1120 {
295  SELECT big.rowid, fullkey, atom
296    FROM big, json_tree(big.json)
297   WHERE atom IS NOT NULL
298   ORDER BY +big.rowid, +json_tree.id
299} $correct_answer
300
301do_execsql_test json102-1130 {
302  SELECT DISTINCT json_extract(big.json,'$.id')
303    FROM big, json_tree(big.json,'$.partlist')
304   WHERE json_tree.key='uuid'
305     AND json_tree.value='6fa5181e-5721-11e5-a04e-57f3d7b32808';
306} {123}
307do_execsql_test json102-1131 {
308  SELECT DISTINCT json_extract(big.json,'$.id')
309    FROM big, json_tree(big.json,'$')
310   WHERE json_tree.key='uuid'
311     AND json_tree.value='6fa5181e-5721-11e5-a04e-57f3d7b32808';
312} {123}
313do_execsql_test json102-1132 {
314  SELECT DISTINCT json_extract(big.json,'$.id')
315    FROM big, json_tree(big.json)
316   WHERE json_tree.key='uuid'
317     AND json_tree.value='6fa5181e-5721-11e5-a04e-57f3d7b32808';
318} {123}
319} ;# end ifcapable vtab
320
321#-------------------------------------------------------------------------
322# Test that json_valid() correctly identifies non-ascii range
323# characters as non-whitespace.
324#
325do_execsql_test json102-1201 { SELECT json_valid(char(32)  || '"xyz"') } 1
326do_execsql_test json102-1202 { SELECT json_valid(char(200) || '"xyz"') } 0
327
328# Off-by-one error in jsonAppendString()
329#
330for {set i 0} {$i<100} {incr i} {
331  set str abcdef[string repeat \" [expr {$i+50}]]uvwxyz
332  do_test json102-[format %d [expr {$i+1300}]] {
333    db eval {SELECT json_extract(json_array($::str),'$[0]')==$::str}
334  } {1}
335}
336
337#-------------------------------------------------------------------------
338# 2017-04-08 ticket b93be8729a895a528e2849fca99f7
339# JSON extension accepts invalid numeric values
340#
341# JSON does not allow leading zeros.  But the JSON extension was
342# allowing them.  The following tests verify that the problem is now
343# fixed.
344#
345do_execsql_test json102-1401 { SELECT json_valid('{"x":01}') } 0
346do_execsql_test json102-1402 { SELECT json_valid('{"x":-01}') } 0
347do_execsql_test json102-1403 { SELECT json_valid('{"x":0}') } 1
348do_execsql_test json102-1404 { SELECT json_valid('{"x":-0}') } 1
349do_execsql_test json102-1405 { SELECT json_valid('{"x":0.1}') } 1
350do_execsql_test json102-1406 { SELECT json_valid('{"x":-0.1}') } 1
351do_execsql_test json102-1407 { SELECT json_valid('{"x":0.0000}') } 1
352do_execsql_test json102-1408 { SELECT json_valid('{"x":-0.0000}') } 1
353do_execsql_test json102-1409 { SELECT json_valid('{"x":01.5}') } 0
354do_execsql_test json102-1410 { SELECT json_valid('{"x":-01.5}') } 0
355do_execsql_test json102-1411 { SELECT json_valid('{"x":00}') } 0
356do_execsql_test json102-1412 { SELECT json_valid('{"x":-00}') } 0
357
358#------------------------------------------------------------------------
359# 2017-04-10 ticket 6c9b5514077fed34551f98e64c09a10dc2fc8e16
360# JSON extension accepts strings containing control characters.
361#
362# The JSON spec requires that all control characters be escaped.
363#
364do_execsql_test json102-1500 {
365  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<0x20)
366  SELECT x FROM c WHERE json_valid(printf('{"a":"x%sz"}', char(x))) ORDER BY x;
367} {32}
368
369# All control characters are escaped
370#
371do_execsql_test json102-1501 {
372  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<0x1f)
373  SELECT sum(json_valid(json_quote('a'||char(x)||'z'))) FROM c ORDER BY x;
374} {31}
375
376finish_test
377