#!/usr/bin/env tclsh set testdir [file dirname $argv0] source $testdir/tester.tcl do_execsql_test json5-ecma-script-1 { select json('{a:5,b:6}') ; } {{{"a":5,"b":6}}} do_execsql_test json5-ecma-script-2 { select json('{a:5,a:3}') ; } {{{"a":5,"a":3}}} do_execsql_test json5-ecma-script-3 { SELECT json('{ MNO_123$xyz : 789 }'); } {{{"MNO_123$xyz":789}}} do_execsql_test json5-with-single-trailing-comma-valid { select json('{"a":5, "b":6, }'); } {{{"a":5,"b":6}}} do_execsql_test json5-single-quoted { SELECT json('{"a": ''abcd''}'); } {{{"a":"abcd"}}} do_execsql_test json5-hexadecimal-1 { SELECT json('{a: 0x0}') } {{{"a":0}}} do_execsql_test json5-hexadecimal-2 { SELECT json('{a: 0xabcdef}') } {{{"a":11259375}}} do_execsql_test json5-hexadecimal-2 { SELECT json('{a: -0xabcdef}') } {{{"a":-11259375}}} do_execsql_test json5-number-1 { SELECT json('{x: 4.}') } {{{"x":4.0}}} do_execsql_test json5-number-2 { SELECT json('{x: +4.}') } {{{"x":4.0}}} do_execsql_test json5-number-3 { SELECT json('{x: -4.}') } {{{"x":-4.0}}} do_execsql_test json5-number-5 { SELECT json('{x: Infinity}') } {{{"x":9e999}}} do_execsql_test json5-number-6 { SELECT json('{x: -Infinity}') } {{{"x":-9e999}}} do_execsql_test json5-multi-comment { SELECT json(' /* abc */ { /*def*/ aaa /* xyz */ : // to the end of line 123 /* xyz */ , /* 123 */ }') } {{{"aaa":123}}} do_execsql_test json5-ecma-script-1-pretty { select json_pretty('{a:5,b:6}') ; } {{{ "a": 5, "b": 6 }}} do_execsql_test json5-ecma-script-2-pretty { select json_pretty('{a:5,a:3}') ; } {{{ "a": 5, "a": 3 }}} do_execsql_test json5-ecma-script-3-pretty { SELECT json_pretty('{ MNO_123$xyz : 789 }'); } {{{ "MNO_123$xyz": 789 }}} do_execsql_test json5-with-single-trailing-comma-valid-pretty { select json_pretty('{"a":5, "b":6, }'); } {{{ "a": 5, "b": 6 }}} do_execsql_test json5-single-quoted-pretty { SELECT json_pretty('{"a": ''abcd''}'); } {{{ "a": "abcd" }}} do_execsql_test json5-hexadecimal-1-pretty { SELECT json_pretty('{a: 0x0}'); } {{{ "a": 0 }}} do_execsql_test json5-hexadecimal-2-pretty { SELECT json_pretty('{a: 0xabcdef}'); } {{{ "a": 11259375 }}} do_execsql_test json5-hexadecimal-2-pretty { SELECT json_pretty('{a: -0xabcdef}'); } {{{ "a": -11259375 }}} do_execsql_test json5-number-1-pretty { SELECT json_pretty('{x: 4.}'); } {{{ "x": 4.0 }}} do_execsql_test json5-number-2-pretty { SELECT json_pretty('{x: +4.}'); } {{{ "x": 4.0 }}} do_execsql_test json5-number-3-pretty { SELECT json_pretty('{x: -4.}'); } {{{ "x": -4.0 }}} do_execsql_test json5-number-5-pretty { SELECT json_pretty('{x: Infinity}'); } {{{ "x": 9e999 }}} do_execsql_test json5-number-6-pretty { SELECT json_pretty('{x: -Infinity}'); } {{{ "x": -9e999 }}} do_execsql_test json5-multi-comment-pretty { SELECT json_pretty(' /* abc */ { /*def*/ aaa /* xyz */ : // to the end of line 123 /* xyz */ , /* 123 */ }'); } {{{ "aaa": 123 }}} do_execsql_test json-pretty-ident-1 { SELECT json_pretty('{x: 1}', ''); } {{{ "x": 1 }}} do_execsql_test json-pretty-ident-2 { SELECT json_pretty('{x: 1}', '11'); } {{{ 11"x": 1 }}} do_execsql_test json-pretty-ident-null { SELECT json_pretty('{x: 1}', NULL); } {{{ "x": 1 }}} do_execsql_test json-pretty-ident-blob-1 { SELECT json_pretty('{x: 1}', x'33'); } {{{ 3"x": 1 }}} # TODO # Currently conversion from blob to string is not exactly the same as in sqlite. # The blob below should evaluate to two whitespaces TEXT value # do_execsql_test json-pretty-ident-blob-2 { # SELECT json_pretty('{x: 1}', x'1111'); # } {{{ # "x": 1 # }}} do_execsql_test json_array_str { SELECT json_array('a') } {{["a"]}} do_execsql_test json_array_numbers { SELECT json_array(1, 1.5) } {{[1,1.5]}} do_execsql_test json_array_numbers_2 { SELECT json_array(1., +2., -2.) } {{[1.0,2.0,-2.0]}} do_execsql_test json_array_null { SELECT json_array(null) } {{[null]}} do_execsql_test json_array_not_json { SELECT json_array('{"a":1}') } {{["{\"a\":1}"]}} do_execsql_test json_array_json { SELECT json_array(json('{"a":1}')) } {{[{"a":1}]}} do_execsql_test json_array_nested { SELECT json_array(json_array(1,2,3), json('[1,2,3]'), '[1,2,3]') } {{[[1,2,3],[1,2,3],"[1,2,3]"]}} do_execsql_test json_extract_null { SELECT json_extract(null, '$') } {{}} do_execsql_test json_extract_json_null_type { SELECT typeof(json_extract('null', '$')) } {{null}} do_execsql_test json_arrow_json_null_type { SELECT typeof('null' -> '$') } {{text}} do_execsql_test json_arrow_shift_json_null_type { SELECT typeof('null' ->> '$') } {{null}} do_execsql_test json_extract_empty { SELECT json_extract() } {{}} do_execsql_test json_extract_single_param { SELECT json_extract(1) } {{}} do_execsql_test json_extract_null_invalid_path { SELECT json_extract(null, 1) } {{}} do_execsql_test json_extract_null_invalid_path_2 { SELECT json_extract(null, CAST(1 AS BLOB)) } {{}} do_execsql_test json_extract_multiple_nulls { SELECT json_extract(null, CAST(1 AS BLOB), null, 1, 2, 3) } {{}} do_execsql_test json_extract_number { SELECT json_extract(1, '$') } {{1}} do_execsql_test json_extract_number_type { SELECT typeof(json_extract(1, '$')) } {{integer}} do_execsql_test json_arrow_number { SELECT 1 -> '$' } {{1}} do_execsql_test json_arrow_number_type { SELECT typeof(1 -> '$') } {{text}} do_execsql_test json_arrow_shift_number { SELECT 1 -> '$' } {{1}} do_execsql_test json_arrow_shift_number_type { SELECT typeof(1 ->> '$') } {{integer}} do_execsql_test json_extract_object_1 { SELECT json_extract('{"a": [1,2,3]}', '$.a') } {{[1,2,3]}} do_execsql_test json_arrow_object { SELECT '{"a": [1,2,3]}' -> '$.a' } {{[1,2,3]}} do_execsql_test json_arrow_blob_object { SELECT cast('{"age":30,"name":"John"}' as blob) -> '$.age' } {{30}} # Tests against valid jsonb [b'{',.., b'}'] vs json text '{..}' # b'{' = ElementType::Array, PayloadSize of 7. # b'}' = last element in array ends in '}' # x'7B0707070707177D' = jsonb(["", "", "", "", "", "}"]) do_execsql_test json_arrow_blob_array { SELECT x'7B0707070707177D' -> '$[5]' } {\"\}\"} # Tests against valid jsonb [b'[',.., b']'] vs json text '[..]' # b'[' = ElementType::Array, PayloadSize of 5. # b']' = last element in array ends in ']' # x'5B070707175D' = jsonb(["", "", "", "}"]) do_execsql_test json_arrow_blob_array_2 { SELECT x'5B070707175D' -> '$[3]' } {\"\]\"} do_execsql_test json_arrow_blob_number { SELECT cast('4' as blob) -> '$' } {{4}} do_execsql_test json_arrow_blob_number_2 { SELECT cast(33 as blob) -> '$' } {{33}} # jsonb(333) do_execsql_test json_arrow_blob_number_3 { SELECT x'33333333' -> '$' } {{333}} do_execsql_test json_arrow_blob_negative_number { SELECT cast('-4' as blob) -> '$' } {{-4}} do_execsql_test json_arrow_shift_blob { SELECT cast('{"age":30,"name":"John"}' as blob) ->> '$.age' } {{30}} do_execsql_test json_extract_object_2 { SELECT json_extract('{"a": [1,2,3]}', '$.a', '$.a[0]', '$.a[1]', '$.a[3]') } {{[[1,2,3],1,2,null]}} do_execsql_test json_extract_object_3 { SELECT json_extract('{"a": [1,2,3]}', '$.a', '$.a[0]', '$.a[1]', null, '$.a[3]') } {{}} # \x61 is the ASCII code for 'a' do_execsql_test json_extract_with_escaping { SELECT json_extract('{"\x61": 1}', '$.a') } {{1}} do_execsql_test json_extract_with_escaping_2 { SELECT json_extract('{"a": 1}', '$."\x61"') } {{1}} do_execsql_test json_extract_null_path { SELECT json_extract(1, null) } {{}} do_execsql_test json_arrow_null_path { SELECT 1 -> null } {{}} do_execsql_test json_arrow_shift_null_path { SELECT 1 ->> null } {{}} do_execsql_test json_extract_float { SELECT typeof(json_extract(1.0, '$')) } {{real}} do_execsql_test json_arrow_float { SELECT typeof(1.0 -> '$') } {{text}} do_execsql_test json_arrow_shift_float { SELECT typeof(1.0 ->> '$') } {{real}} do_execsql_test json_extract_true { SELECT json_extract('true', '$') } {{1}} do_execsql_test json_extract_true_type { SELECT typeof(json_extract('true', '$')) } {{integer}} do_execsql_test json_arrow_true { SELECT 'true' -> '$' } {{true}} do_execsql_test json_arrow_true_type { SELECT typeof('true' -> '$') } {{text}} do_execsql_test json_arrow_shift_true { SELECT 'true' ->> '$' } {{1}} do_execsql_test json_arrow_shift_true_type { SELECT typeof('true' ->> '$') } {{integer}} do_execsql_test json_extract_false { SELECT json_extract('false', '$') } {{0}} do_execsql_test json_extract_false_type { SELECT typeof(json_extract('false', '$')) } {{integer}} do_execsql_test json_arrow_false { SELECT 'false' -> '$' } {{false}} do_execsql_test json_arrow_false_type { SELECT typeof('false' -> '$') } {{text}} do_execsql_test json_arrow_shift_false { SELECT 'false' ->> '$' } {{0}} do_execsql_test json_arrow_shift_false_type { SELECT typeof('false' ->> '$') } {{integer}} do_execsql_test json_extract_string { SELECT json_extract('"string"', '$') } {{string}} do_execsql_test json_extract_string_type { SELECT typeof(json_extract('"string"', '$')) } {{text}} do_execsql_test json_arrow_string { SELECT '"string"' -> '$' } {{"string"}} do_execsql_test json_arrow_string_type { SELECT typeof('"string"' -> '$') } {{text}} do_execsql_test json_arrow_shift_string { SELECT '"string"' ->> '$' } {{string}} do_execsql_test json_arrow_shift_string_type { SELECT typeof('"string"' ->> '$') } {{text}} do_execsql_test json_arrow_implicit_root_path { SELECT '{"a":1}' -> 'a'; } {{1}} do_execsql_test json_arrow_shift_implicit_root_path { SELECT '{"a":1}' ->> 'a'; } {{1}} do_execsql_test json_arrow_implicit_root_path_undefined_key { SELECT '{"a":1}' -> 'x'; } {{}} do_execsql_test json_arrow_shift_implicit_root_path_undefined_key { SELECT '{"a":1}' ->> 'x'; } {{}} do_execsql_test json_arrow_implicit_root_path_array { SELECT '[1,2,3]' -> 1; } {{2}} do_execsql_test json_arrow_shift_implicit_root_path_array { SELECT '[1,2,3]' ->> 1; } {{2}} do_execsql_test json_arrow_implicit_root_path_array_negative_idx { SELECT '[1,2,3]' -> -1; } {{3}} do_execsql_test json_arrow_shift_implicit_root_path_array_negative_idx { SELECT '[1,2,3]' ->> -1; } {{3}} do_execsql_test json_arrow_implicit_real_cast { SELECT '{"1.5":"abc"}' -> 1.5; } {{"abc"}} do_execsql_test json_arrow_shift_implicit_real_cast { SELECT '{"1.5":"abc"}' -> 1.5; } {{"abc"}} do_execsql_test json_arrow_implicit_true_cast { SELECT '[1,2,3]' -> true } {{2}} do_execsql_test json_arrow_shift_implicit_true_cast { SELECT '[1,2,3]' ->> true } {{2}} do_execsql_test json_arrow_implicit_false_cast { SELECT '[1,2,3]' -> false } {{1}} do_execsql_test json_arrow_shift_implicit_false_cast { SELECT '[1,2,3]' ->> false } {{1}} do_execsql_test json_arrow_chained { select '{"a":2,"c":[4,5,{"f":7}]}' -> 'c' -> 2 ->> 'f' } {{7}} do_execsql_test json_extract_multiple_null_paths { SELECT json_extract(1, null, null, null) } {{}} do_execsql_test json_extract_array { SELECT json_extract('[1,2,3]', '$') } {{[1,2,3]}} do_execsql_test json_arrow_array { SELECT '[1,2,3]' -> '$' } {{[1,2,3]}} do_execsql_test json_arrow_shift_array { SELECT '[1,2,3]' ->> '$' } {{[1,2,3]}} do_execsql_test json_extract_quote { SELECT json_extract('{"\"":1 }', '$."\""') } {{1}} # Overflows 2**32 is equivalent to 0 do_execsql_test json_extract_overflow_int32_1 { SELECT json_extract('[1,2,3]', '$[4294967296]') } {{1}} # Overflows 2**32 + 1 is equivalent to 1 do_execsql_test json_extract_overflow_int32_2 { SELECT json_extract('[1,2,3]', '$[4294967297]') } {{2}} # Overflows -2**32 - 1 is equivalent to -1 do_execsql_test json_extract_overflow_int32_3 { SELECT json_extract('[1,2,3]', '$[#-4294967297]') } {{3}} # Overflows -2**32 - 2 is equivalent to -2 do_execsql_test json_extract_overflow_int32_3 { SELECT json_extract('[1,2,3]', '$[#-4294967298]') } {{2}} # pow(2,63) + 1 == 9223372036854775808 do_execsql_test json_extract_overflow_int64 { SELECT json_extract('[1,2,3]', '$[9223372036854775808]'); } {{1}} # TODO: fix me - this passes on SQLite and needs to be fixed in Limbo. # pow(2, 127) + 1 == 170141183460469231731687303715884105729 #do_execsql_test json_extract_overflow_int128 { # SELECT json_extract('[1, 2, 3]', '$[170141183460469231731687303715884105729]'); #} {{2}} do_execsql_test json_extract_blob { select json_extract(CAST('[1,2,3]' as BLOB), '$[1]') } {{2}} do_execsql_test json_array_length { SELECT json_array_length('[1,2,3,4]'); } {{4}} do_execsql_test json_array_length_empty { SELECT json_array_length('[]'); } {{0}} do_execsql_test json_array_length_root { SELECT json_array_length('[1,2,3,4]', '$'); } {{4}} do_execsql_test json_array_length_not_array { SELECT json_array_length('{"one":[1,2,3]}'); } {{0}} do_execsql_test json_array_length_via_prop { SELECT json_array_length('{"one":[1,2,3]}', '$.one'); } {{3}} do_execsql_test json_array_length_via_index { SELECT json_array_length('[[1,2,3,4]]', '$[0]'); } {{4}} do_execsql_test json_array_length_via_index_not_array { SELECT json_array_length('[1,2,3,4]', '$[2]'); } {{0}} do_execsql_test json_array_length_via_bad_prop { SELECT json_array_length('{"one":[1,2,3]}', '$.two'); } {{}} do_execsql_test json_array_length_nested { SELECT json_array_length('{"one":[[1,2,3],2,3]}', '$.one[0]'); } {{3}} do_execsql_test json_type_no_path { select json_type('{"a":[2,3.5,true,false,null,"x"]}') } {{object}} do_execsql_test json_type_root_path { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$') } {{object}} do_execsql_test json_type_array { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a') } {{array}} do_execsql_test json_type_integer { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[0]') } {{integer}} do_execsql_test json_type_real { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[1]') } {{real}} do_execsql_test json_type_true { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[2]') } {{true}} do_execsql_test json_type_false { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[3]') } {{false}} do_execsql_test json_type_null { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[4]') } {{null}} do_execsql_test json_type_text { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[5]') } {{text}} do_execsql_test json_type_NULL { select json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[6]') } {{}} do_execsql_test json_type_cast { select json_type(1) } {{integer}} do_execsql_test json_type_null_arg { select json_type(null) } {{}} do_execsql_test json_error_position_valid { SELECT json_error_position('{"a":55,"b":72,}'); } {{0}} do_execsql_test json_error_position_valid_ws { SELECT json_error_position('{"a":55,"b":72 , }'); } {{0}} do_execsql_test json_error_position_object { SELECT json_error_position('{"a":55,"b":72,,}'); } {{16}} do_execsql_test json_error_position_array_valid { SELECT json_error_position('["a",55,"b",72,]'); } {{0}} do_execsql_test json_error_position_array_valid_ws { SELECT json_error_position('["a",55,"b",72 , ]'); } {{0}} do_execsql_test json_error_position_array { SELECT json_error_position('["a",55,"b",72,,]'); } {{16}} do_execsql_test json_error_position_null { SELECT json_error_position(NULL); } {{}} do_execsql_test json_error_position_complex { SELECT json_error_position('{a:null,{"h":[1,[1,2,3]],"j":"abc"}:true}'); } {{9}} do_execsql_test json_object_simple { SELECT json_object('key', 'value'); } {{{"key":"value"}}} do_execsql_test json_object_f64 { SELECT json_object('key', 40.7128); } {{{"key":40.7128}}} do_execsql_test json_object_nested { SELECT json_object('grandparent',json_object('parent', json_object('child', 'value'))); } {{{"grandparent":{"parent":{"child":"value"}}}}} do_execsql_test json_object_quoted_json { SELECT json_object('parent', '{"child":"value"}'); } {{{"parent":"{\"child\":\"value\"}"}}} do_execsql_test json_object_unquoted_json { SELECT json_object('parent', json('{"child":"value"}')); } {{{"parent":{"child":"value"}}}} do_execsql_test json_object_multiple_values { SELECT json_object('text', 'value', 'json', json_object('key', 'value'), 'int', 1, 'float', 1.5, 'null', null); } {{{"text":"value","json":{"key":"value"},"int":1,"float":1.5,"null":null}}} do_execsql_test json_object_empty { SELECT json_object(); } {{{}}} do_execsql_test json_object_json_array { SELECT json_object('ex',json('[52,3]')); } {{{"ex":[52,3]}}} do_execsql_test json_from_json_object { SELECT json(json_object('key','value')); } {{{"key":"value"}}} # FIXME: this behaviour differs from sqlite. Although, sqlite docs states # that this could change in a "future enhancement" (https://www.sqlite.org/json1.html#jobj) do_execsql_test json_object_duplicated_keys { SELECT json_object('key', 'value', 'key', 'value2'); } {{{"key":"value","key":"value2"}}} do_execsql_test json_valid_1 { SELECT json_valid('{"a":55,"b":72}'); } {1} do_execsql_test json_valid_2 { SELECT json_valid('["a",55,"b",72]'); } {1} do_execsql_test json_valid_3 { SELECT json_valid( CAST('{"a":"1}' AS BLOB) ); } {0} do_execsql_test json_valid_4 { SELECT json_valid(123); } {1} do_execsql_test json_valid_5 { SELECT json_valid(12.3); } {1} do_execsql_test json_valid_6 { SELECT json_valid('not a valid json'); } {0} do_execsql_test json_valid_7 { SELECT json_valid('{"a":"55,"b":72}'); } {0} do_execsql_test json_valid_8 { SELECT json_valid('{"a":55 "b":72}'); } {0} do_execsql_test json_valid_9 { SELECT json_valid(NULL); } {} do_execsql_test json-patch-basic-1 { select json_patch('{"a":1}', '{"b":2}'); } {{{"a":1,"b":2}}} do_execsql_test json-patch-basic-2 { select json_patch('{"x":100,"y":200}', '{"z":300}'); } {{{"x":100,"y":200,"z":300}}} do_execsql_test json-patch-preserve-duplicates-1 { select json_patch('{"x":100,"x":200}', '{"z":300}'); } {{{"x":100,"x":200,"z":300}}} do_execsql_test json-patch-preserve-duplicates-2 { select json_patch('{"x":100,"x":200}', '{"x":900}'); } {{{"x":900,"x":200}}} do_execsql_test json-patch-last-update-wins { select json_patch('{"x":100,"c":200}', '{"x":900, "x":null}'); } {{{"c":200}}} do_execsql_test json-patch-override-1 { select json_patch('{"a":1,"b":2}', '{"b":3}'); } {{{"a":1,"b":3}}} do_execsql_test json-patch-override-2 { select json_patch('{"name":"john","age":25}', '{"age":26,"city":"NYC"}'); } {{{"name":"john","age":26,"city":"NYC"}}} do_execsql_test json-patch-nested-1 { select json_patch('{"user":{"name":"john"}}', '{"user":{"age":30}}'); } {{{"user":{"name":"john","age":30}}}} do_execsql_test json-patch-nested-2 { select json_patch('{"settings":{"theme":"dark"}}', '{"settings":{"theme":"light","font":"arial"}}'); } {{{"settings":{"theme":"light","font":"arial"}}}} do_execsql_test json-patch-array-1 { select json_patch('{"arr":[1,2,3]}', '{"arr":[4,5,6]}'); } {{{"arr":[4,5,6]}}} do_execsql_test json-patch-array-2 { select json_patch('{"list":["a","b"]}', '{"list":["c"]}'); } {{{"list":["c"]}}} do_execsql_test json-patch-empty-1 { select json_patch('{}', '{"a":1}'); } {{{"a":1}}} do_execsql_test json-patch-empty-2 { select json_patch('{"a":1}', '{}'); } {{{"a":1}}} do_execsql_test json-patch-deep-nested-1 { select json_patch( '{"level1":{"level2":{"value":100}}}', '{"level1":{"level2":{"newValue":200}}}' ); } {{{"level1":{"level2":{"value":100,"newValue":200}}}}} do_execsql_test json-patch-mixed-types-1 { select json_patch( '{"str":"hello","num":42,"bool":true}', '{"arr":[1,2,3],"obj":{"x":1}}' ); } {{{"str":"hello","num":42,"bool":true,"arr":[1,2,3],"obj":{"x":1}}}} do_execsql_test json-patch-add-all-dup-keys-from-patch { select json_patch( '{"x":100,"x":200}', '{"z":{}, "z":5, "z":100}' ); } {{{"x":100,"x":200,"z":100}}} do_execsql_test json-patch-first-occurrence-patch { select json_patch('{"x":100,"x":200}','{"x":{}, "x":5, "x":100}'); } {{{"x":100,"x":200}}} do_execsql_test json-patch-complex-nested-dup-keys { select json_patch( '{"a":{"x":1,"x":2},"a":{"y":3},"b":[{"z":4,"z":5}]}', '{"a":{"w":6},"b":[{"z":7,"z":8}],"b":{"z":9}}' ); } {{{"a":{"x":1,"x":2,"w":6},"a":{"y":3},"b":{"z":9}}}} do_execsql_test json-patch-unicode-dup-keys { select json_patch( '{"πŸ”‘":1,"πŸ”‘":2}', '{"πŸ—οΈ":3,"πŸ—οΈ":4}' ); } {{{"πŸ”‘":1,"πŸ”‘":2,"πŸ—οΈ":4}}} do_execsql_test json-patch-empty-string-dup-keys { select json_patch( '{"":1,"":2}', '{"":3,"":4}' ); } {{{"":4,"":2}}} do_execsql_test json-patch-multiple-types-dup-keys { select json_patch( '{"x":100,"x":"str","x":true,"x":null}', '{"y":1,"y":{},"y":[],"y":false}' ); } {{{"x":100,"x":"str","x":true,"x":null,"y":false}}} do_execsql_test json-patch-deep-nested-dup-keys { select json_patch( '{"a":{"b":{"c":1}},"a":{"b":{"c":2}},"a":{"b":{"d":3}}}', '{"x":{"y":{"z":4}},"x":{"y":{"z":5}}}' ); } {{{"a":{"b":{"c":1}},"a":{"b":{"c":2}},"a":{"b":{"d":3}},"x":{"y":{"z":5}}}}} do_execsql_test json-patch-abomination { select json_patch( '{"a":{"b":{"x":1,"x":2,"y":{"z":3,"z":{"w":4}}},"b":[{"c":5,"c":6},{"d":{"e":7,"e":null}}],"f":{"g":[1,2,3],"g":{"h":8,"h":[4,5,6]}},"i":{"j":true,"j":{"k":false,"k":{"l":null,"l":"string"}}},"m":{"n":{"o":{"p":9,"p":{"q":10}},"o":{"r":11}}},"m":[{"s":{"t":12}},{"s":{"t":13,"t":{"u":14}}}]},"a":{"v":{"w":{"x":{"y":{"z":15}}}},"v":{"w":{"x":16,"x":{"y":17}}},"aa":[{"bb":{"cc":18,"cc":{"dd":19}}},{"bb":{"cc":{"dd":20},"cc":21}}]}}', '{"a":{"b":{"x":{"new":"value"},"y":null},"b":{"c":{"updated":true},"d":{"e":{"replaced":100}}},"f":{"g":{"h":{"nested":"deep"}}},"i":{"j":{"k":{"l":{"modified":false}}}},"m":{"n":{"o":{"p":{"q":{"extra":"level"}}}},"s":null},"aa":[{"bb":{"cc":{"dd":{"ee":"new"}}}},{"bb":{"cc":{"dd":{"ff":"value"}}}}],"v":{"w":{"x":{"y":{"z":{"final":"update"}}}}}},"newTop":{"level":{"key":{"with":{"deep":{"nesting":true}}},"key":[{"array":{"in":{"deep":{"structure":null}}}}]}}}' ); } {{{"a":{"b":{"x":{"new":"value"},"x":2,"c":{"updated":true},"d":{"e":{"replaced":100}}},"b":[{"c":5,"c":6},{"d":{"e":7,"e":null}}],"f":{"g":{"h":{"nested":"deep"}},"g":{"h":8,"h":[4,5,6]}},"i":{"j":{"k":{"l":{"modified":false}}},"j":{"k":false,"k":{"l":null,"l":"string"}}},"m":{"n":{"o":{"p":{"q":{"extra":"level"}},"p":{"q":10}},"o":{"r":11}}},"m":[{"s":{"t":12}},{"s":{"t":13,"t":{"u":14}}}],"aa":[{"bb":{"cc":{"dd":{"ee":"new"}}}},{"bb":{"cc":{"dd":{"ff":"value"}}}}],"v":{"w":{"x":{"y":{"z":{"final":"update"}}}}}},"a":{"v":{"w":{"x":{"y":{"z":15}}}},"v":{"w":{"x":16,"x":{"y":17}}},"aa":[{"bb":{"cc":18,"cc":{"dd":19}}},{"bb":{"cc":{"dd":20},"cc":21}}]},"newTop":{"level":{"key":[{"array":{"in":{"deep":{"structure":null}}}}]}}}}} do_execsql_test json-remove-1 { select json_remove('{"a": 5, "a": [5,4,3,2,1]}','$.a', '$.a[4]', '$.a[5]', '$.a'); } {{{}}} do_execsql_test json-remove-2 { SELECT json_remove('{"a": {"b": {"c": 1, "c": 2}, "b": [1,2,3]}}', '$.a.b.c', '$.a.b[1]'); } {{{"a":{"b":{"c":2},"b":[1,2,3]}}}} do_execsql_test json-remove-3 { SELECT json_remove('[1,2,3,4,5]', '$[0]', '$[4]', '$[5]'); } {{[2,3,4,5]}} do_execsql_test json-remove-4 { SELECT json_remove('{"arr": [1,2,3,4,5]}', '$.arr[#-1]', '$.arr[#-3]', '$.arr[#-1]'); } {{{"arr":[1,3]}}} do_execsql_test json-remove-5 { SELECT json_remove('{}', '$.a'); } {{{}}} do_execsql_test json-remove-6 { SELECT json_remove('{"a": [[1,2], [3,4]]}', '$.a[0][1]', '$.a[1]'); } {{{"a":[[1]]}}} do_execsql_test json-remove-7 { SELECT json_remove('{"a": 1, "b": [1,2], "c": {"d": 3}}', '$.a', '$.b[0]', '$.c.d'); } {{{"b":[2],"c":{}}}} do_execsql_test json-remove-8 { SELECT json_remove(cast('{"age":30,"name":"John"}' as blob), '$.age'); } {{{"name":"John"}}} do_execsql_test json-remove-9 { SELECT json_remove(cast('{"user":{"id":123,"profile":{"name":"Alice","age":25}}}' as blob), '$.user.id'); } {{{"user":{"profile":{"name":"Alice","age":25}}}}} do_execsql_test json_set_field_empty_object { SELECT json_set('{}', '$.field', 'value'); } {{{"field":"value"}}} do_execsql_test json_set_replace_field { SELECT json_set('{"field":"old_value"}', '$.field', 'new_value'); } {{{"field":"new_value"}}} do_execsql_test json_set_replace_field_2 { SELECT json_set(cast('{"age":30,"name":"John"}' as blob), '$.age', 40); } {{{"age":40,"name":"John"}}} do_execsql_test json_set_set_deeply_nested_key { SELECT json_set('{}', '$.object.doesnt.exist', 'value'); } {{{"object":{"doesnt":{"exist":"value"}}}}} do_execsql_test json_set_add_value_to_empty_array { SELECT json_set('[]', '$[0]', 'value'); } {{["value"]}} do_execsql_test json_set_add_value_to_nonexistent_array { SELECT json_set('{}', '$.some_array[0]', 123); } {{{"some_array":[123]}}} do_execsql_test json_set_add_value_to_array { SELECT json_set('[123]', '$[1]', 456); } {{[123,456]}} do_execsql_test json_set_add_value_to_array_out_of_bounds { SELECT json_set('[123]', '$[200]', 456); } {{[123]}} do_execsql_test json_set_replace_value_in_array { SELECT json_set('[123]', '$[0]', 456); } {{[456]}} do_execsql_test json_set_null_path { SELECT json_set('{}', NULL, 456); } {{{}}} do_execsql_test json_set_multiple_keys { SELECT json_set('[123]', '$[0]', 456, '$[1]', 789); } {{[456,789]}} do_execsql_test json_set_add_array_in_nested_object { SELECT json_set('{}', '$.object[0].field', 123); } {{{"object":[{"field":123}]}}} do_execsql_test json_set_add_array_in_array_in_nested_object { SELECT json_set('{}', '$.object[0][0]', 123); } {{{"object":[[123]]}}} do_execsql_test json_set_add_array_in_array_in_nested_object_out_of_bounds { SELECT json_set('{}', '$.object[123].another', 'value', '$.field', 'value'); } {{{"field":"value"}}} # The json_quote() function transforms an SQL value into a JSON value. # String values are quoted and interior quotes are escaped. NULL values # are rendered as the unquoted string "null". # do_execsql_test json_quote_string_literal { SELECT json_quote('abc"xyz'); } {{"abc\"xyz"}} do_execsql_test json_quote_float { SELECT json_quote(3.14159); } {3.14159} do_execsql_test json_quote_integer { SELECT json_quote(12345); } {12345} do_execsql_test json_quote_null { SELECT json_quote(null); } {"null"} do_execsql_test json_quote_null_caps { SELECT json_quote(NULL); } null do_execsql_test json_quote_json_value { SELECT json_quote(json('{a:1, b: "test"}')); } {{{"a":1,"b":"test"}}} do_execsql_test json_basics { SELECT json(jsonb('{"name":"John", "age":30, "city":"New York"}')); } {{{"name":"John","age":30,"city":"New York"}}} do_execsql_test json_complex_nested { SELECT json(jsonb('{"complex": {"nested": ["array", "of", "values"], "numbers": [1, 2, 3]}}')); } {{{"complex":{"nested":["array","of","values"],"numbers":[1,2,3]}}}} do_execsql_test json_array_of_objects { SELECT json(jsonb('[{"id": 1, "data": "value1"}, {"id": 2, "data": "value2"}]')); } {{[{"id":1,"data":"value1"},{"id":2,"data":"value2"}]}} do_execsql_test json_special_chars { SELECT json(jsonb('{"special_chars": "!@#$%^&*()_+", "quotes": "\"quoted text\""}')); } {{{"special_chars":"!@#$%^&*()_+","quotes":"\"quoted text\""}}} do_execsql_test json_unicode_emoji { SELECT json(jsonb('{"unicode": "γ“γ‚“γ«γ‘γ―δΈ–η•Œ", "emoji": "πŸš€πŸ”₯πŸ’―"}')); } {{{"unicode":"γ“γ‚“γ«γ‘γ―δΈ–η•Œ","emoji":"πŸš€πŸ”₯πŸ’―"}}} do_execsql_test json_value_types { SELECT json(jsonb('{"boolean": true, "null_value": null, "number": 42.5}')); } {{{"boolean":true,"null_value":null,"number":42.5}}} do_execsql_test json_deeply_nested { SELECT json(jsonb('{"deeply": {"nested": {"structure": {"with": "values"}}}}')); } {{{"deeply":{"nested":{"structure":{"with":"values"}}}}}} do_execsql_test json_mixed_array { SELECT json(jsonb('{"array_mixed": [1, "text", true, null, {"obj": "inside array"}]}')); } {{{"array_mixed":[1,"text",true,null,{"obj":"inside array"}]}}} do_execsql_test json_single_line_comments { SELECT json(jsonb('{"name": "John", // This is a comment "age": 30}')); } {{{"name":"John","age":30}}} do_execsql_test json_multi_line_comments { SELECT json(jsonb('{"data": "value", /* This is a multi-line comment that spans several lines */ "more": "data"}')); } {{{"data":"value","more":"data"}}} do_execsql_test json_trailing_commas { SELECT json(jsonb('{"items": ["one", "two", "three",], "status": "complete",}')); } {{{"items":["one","two","three"],"status":"complete"}}} do_execsql_test json_unquoted_keys { SELECT json(jsonb('{name: "Alice", age: 25}')); } {{{"name":"Alice","age":25}}} do_execsql_test json_newlines { SELECT json(jsonb('{"description": "Text with \nnew lines\nand more\nformatting"}')); } {{{"description":"Text with \nnew lines\nand more\nformatting"}}} do_execsql_test json_hex_values { SELECT json(jsonb('{"hex_value": "\x68\x65\x6c\x6c\x6f"}')); } {{{"hex_value":"\u0068\u0065\u006c\u006c\u006f"}}} do_execsql_test json_unicode_escape { SELECT json(jsonb('{"unicode": "\u0068\u0065\u006c\u006c\u006f"}')); } {{{"unicode":"\u0068\u0065\u006c\u006c\u006f"}}} do_execsql_test json_tabs_whitespace { SELECT json(jsonb('{"formatted": "Text with \ttabs and \tspacing"}')); } {{{"formatted":"Text with \ttabs and \tspacing"}}} do_execsql_test json_mixed_escaping { SELECT json(jsonb('{"mixed": "Newlines: \n Tabs: \t Quotes: \" Backslash: \\ Hex: \x40"}')); } {{{"mixed":"Newlines: \n Tabs: \t Quotes: \" Backslash: \\ Hex: \u0040"}}} do_execsql_test json_control_chars { SELECT json(jsonb('{"control": "Bell: \u0007 Backspace: \u0008 Form feed: \u000C"}')); } {{{"control":"Bell: \u0007 Backspace: \u0008 Form feed: \u000C"}}} # Tests for json_replace() function # Basic replacement tests do_execsql_test json_replace_basic_1 { SELECT json_replace('{"a": 1, "b": 2}', '$.a', 42) } {{{"a":42,"b":2}}} do_execsql_test json_replace_basic_2 { SELECT json_replace('{"a": 1, "b": 2}', '$.c', 3) } {{{"a":1,"b":2}}} do_execsql_test json_replace_multiple_paths { SELECT json_replace('{"a": 1, "b": 2, "c": 3}', '$.a', 10, '$.c', 30) } {{{"a":10,"b":2,"c":30}}} # Testing different JSON types do_execsql_test json_replace_string { SELECT json_replace('{"name": "Alice"}', '$.name', 'Bob') } {{{"name":"Bob"}}} do_execsql_test json_replace_number_with_string { SELECT json_replace('{"age": 25}', '$.age', 'unknown') } {{{"age":"unknown"}}} do_execsql_test json_replace_with_null { SELECT json_replace('{"a": 1, "b": 2}', '$.a', NULL) } {{{"a":null,"b":2}}} do_execsql_test json_replace_with_json_object { SELECT json_replace('{"user": {"name": "Alice"}}', '$.user', '{"name": "Bob", "age": 30}') } {{{"user":"{\"name\": \"Bob\", \"age\": 30}"}}} # Array tests do_execsql_test json_replace_array_element { SELECT json_replace('[1, 2, 3, 4]', '$[1]', 99) } {{[1,99,3,4]}} do_execsql_test json_replace_array_negative_index { SELECT json_replace('[1, 2, 3, 4]', '$[#-1]', 99) } {{[1,2,3,99]}} do_execsql_test json_replace_array_out_of_bounds { SELECT json_replace('[1, 2, 3]', '$[5]', 99) } {{[1,2,3]}} do_execsql_test json_replace_entire_array { SELECT json_replace('[1, 2, 3]', '$', '{"replaced": true}') } {{"{\"replaced\": true}"}} # Nested structures do_execsql_test json_replace_nested_object { SELECT json_replace('{"user": {"name": "Alice", "age": 30}}', '$.user.age', 31) } {{{"user":{"name":"Alice","age":31}}}} do_execsql_test json_replace_nested_array { SELECT json_replace('{"data": [10, 20, 30]}', '$.data[1]', 99) } {{{"data":[10,99,30]}}} do_execsql_test json_replace_deep_nesting { SELECT json_replace( '{"level1": {"level2": {"level3": {"value": 0}}}}', '$.level1.level2.level3.value', 42 ) } {{{"level1":{"level2":{"level3":{"value":42}}}}}} # Edge cases do_execsql_test json_replace_empty_object { SELECT json_replace('{}', '$.anything', 42) } {{{}}} do_execsql_test json_replace_empty_array { SELECT json_replace('[]', '$[0]', 42) } {{[]}} do_execsql_test json_replace_quoted_key { SELECT json_replace('{"key.with.dots": 1}', '$."key.with.dots"', 42) } {{{"key.with.dots":42}}} do_execsql_test json_replace_root { SELECT json_replace('{"old": "value"}', '$', '{"new": "object"}') } {{"{\"new\": \"object\"}"}} do_execsql_test json_replace_types_boolean { SELECT typeof(json_extract(json_replace('{"flag": null}', '$.flag', 1=1), '$.flag')) } {{integer}} do_execsql_test json_replace_types_integer { SELECT typeof(json_extract(json_replace('{"num": "text"}', '$.num', 42), '$.num')) } {{integer}} do_execsql_test json_replace_types_real { SELECT typeof(json_extract(json_replace('{"num": 1}', '$.num', 3.14), '$.num')) } {{real}} do_execsql_test json_replace_types_text { SELECT typeof(json_extract(json_replace('{"val": 1}', '$.val', 'text'), '$.val')) } {{text}} # Tests for json_remove() function # Basic removal tests do_execsql_test json_remove_basic_1 { SELECT json_remove('{"a": 1, "b": 2, "c": 3}', '$.b') } {{{"a":1,"c":3}}} do_execsql_test json_remove_basic_2 { SELECT json_remove('{"a": 1, "b": 2}', '$.c') } {{{"a":1,"b":2}}} do_execsql_test json_remove_multiple_paths { SELECT json_remove('{"a": 1, "b": 2, "c": 3, "d": 4}', '$.a', '$.c') } {{{"b":2,"d":4}}} # Array tests do_execsql_test json_remove_array_element { SELECT json_remove('[1, 2, 3, 4]', '$[1]') } {{[1,3,4]}} do_execsql_test json_remove_array_negative_index { SELECT json_remove('[1, 2, 3, 4]', '$[#-1]') } {{[1,2,3]}} do_execsql_test json_remove_array_multiple_elements { SELECT json_remove('[0, 1, 2, 3, 4, 5]', '$[1]', '$[3]') } {{[0,2,3,5]}} do_execsql_test json_remove_array_out_of_bounds { SELECT json_remove('[1, 2, 3]', '$[5]') } {{[1,2,3]}} # Nested structures do_execsql_test json_remove_nested_object { SELECT json_remove('{"user": {"name": "Alice", "age": 30, "email": "alice@example.com"}}', '$.user.email') } {{{"user":{"name":"Alice","age":30}}}} do_execsql_test json_remove_nested_array { SELECT json_remove('{"data": [10, 20, 30, 40]}', '$.data[2]') } {{{"data":[10,20,40]}}} do_execsql_test json_remove_deep_nesting { SELECT json_remove( '{"level1": {"level2": {"level3": {"a": 1, "b": 2, "c": 3}}}}', '$.level1.level2.level3.b' ) } {{{"level1":{"level2":{"level3":{"a":1,"c":3}}}}}} # Edge cases do_execsql_test json_remove_empty_object { SELECT json_remove('{}', '$.anything') } {{{}}} do_execsql_test json_remove_empty_array { SELECT json_remove('[]', '$[0]') } {{[]}} do_execsql_test json_remove_quoted_key { SELECT json_remove('{"key.with.dots": 1, "normal": 2}', '$."key.with.dots"') } {{{"normal":2}}} do_execsql_test json_remove_all_properties { SELECT json_remove('{"a": 1, "b": 2}', '$.a', '$.b') } {{{}}} do_execsql_test json_remove_all_array_elements { SELECT json_remove('[1, 2, 3]', '$[0]', '$[0]', '$[0]') } {{[]}} do_execsql_test json_remove_root { SELECT json_remove('{"a": 1}', '$') } {} # Complex example tests do_execsql_test json_remove_complex_1 { SELECT json_remove( '{"store": {"book": [ {"category": "fiction", "author": "Herman Melville", "title": "Moby Dick", "price": 8.99}, {"category": "fiction", "author": "J. R. R. Tolkien", "title": "The Lord of the Rings", "price": 22.99} ], "bicycle": {"color": "red", "price": 19.95}}}', '$.store.book[0].price', '$.store.bicycle' ) } {{{"store":{"book":[{"category":"fiction","author":"Herman Melville","title":"Moby Dick"},{"category":"fiction","author":"J. R. R. Tolkien","title":"The Lord of the Rings","price":22.99}]}}}} do_execsql_test json_replace_complex_1 { SELECT json_replace( '{"store": {"book": [ {"category": "fiction", "author": "Herman Melville", "title": "Moby Dick", "price": 8.99}, {"category": "fiction", "author": "J. R. R. Tolkien", "title": "The Lord of the Rings", "price": 22.99} ], "bicycle": {"color": "red", "price": 19.95}}}', '$.store.book[0].price', 10.99, '$.store.bicycle.color', 'blue', '$.store.book[1].title', 'The Hobbit' ) } {{{"store":{"book":[{"category":"fiction","author":"Herman Melville","title":"Moby Dick","price":10.99},{"category":"fiction","author":"J. R. R. Tolkien","title":"The Hobbit","price":22.99}],"bicycle":{"color":"blue","price":19.95}}}}} # Combination of replace and remove do_execsql_test json_replace_after_remove { SELECT json_replace(json_remove('{"a": 1, "b": 2, "c": 3}', '$.a'), '$.b', 42) } {{{"b":42,"c":3}}} do_execsql_test json_remove_after_replace { SELECT json_remove(json_replace('{"a": 1, "b": 2, "c": 3}', '$.b', 42), '$.c') } {{{"a":1,"b":42}}} # Tests for idempotence do_execsql_test json_replace_idempotence { SELECT json_replace('{"a": 1}', '$.a', 1) } {{{"a":1}}} do_execsql_test json_remove_idempotence { SELECT json_remove(json_remove('{"a": 1, "b": 2}', '$.a'), '$.a') } {{{"b":2}}} # Compare with extracted values do_execsql_test json_remove_with_extract { SELECT json_extract(json_remove('{"a": 1, "b": 2, "c": {"d": 3}}', '$.b'), '$.c.d') } {{3}} do_execsql_test json_replace_with_extract { SELECT json_extract(json_replace('{"a": 1, "b": 2}', '$.a', 42), '$.a') } {{42}} # Check for consistency between -> operator and json_extract after mutations do_execsql_test json_replace_with_arrow { SELECT json_replace('{"a": 1, "b": 2}', '$.a', 42) -> '$.a' } {{42}} do_execsql_test json_remove_with_arrow { SELECT json_remove('{"a": 1, "b": {"c": 3}}', '$.a') -> '$.b.c' } {{3}} # Escape character tests in sqlite source depend on json_valid and in some syntax that is not implemented # yet in limbo. # See https://github.com/sqlite/sqlite/blob/255548562b125e6c148bb27d49aaa01b2fe61dba/test/json102.test#L690 # So for now not all control characters escaped are tested # do_execsql_test json102-1501 { # WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<0x1f) # SELECT sum(json_valid(json_quote('a'||char(x)||'z'))) FROM c ORDER BY x; # } {31} do_execsql_test json_each_arrays_heterogeneous_primitives { SELECT key, atom, type, fullkey, path, typeof(key) AS ktype FROM json_each('[1, 2.5, "x", true, false, null]') ORDER BY key; } { 0|1|integer|$[0]|$|integer 1|2.5|real|$[1]|$|integer 2|x|text|$[2]|$|integer 3|1|true|$[3]|$|integer 4|0|false|$[4]|$|integer 5||null|$[5]|$|integer } do_execsql_test json_each_arrays_parent_is_always_null { SELECT COUNT(*) FROM json_each('[0,1,2]') WHERE parent IS NOT NULL; } {0} do_execsql_test json_each_arrays_id_uniqueness { SELECT COUNT(*), COUNT(DISTINCT id) FROM json_each('[10,20,30,40]'); } {4|4} do_execsql_test json_each_arrays_empty_container_yields_zero_rows { SELECT COUNT(*) FROM json_each('[]'); } {0} do_execsql_test json_each_objects_simple_integer_values { SELECT key, atom, type, fullkey, path, typeof(key) AS ktype FROM json_each('{"a":1,"b":2}') ORDER BY key; } { {a|1|integer|$.a|$|text} {b|2|integer|$.b|$|text} } do_execsql_test json_each_objects_nested_containers_value_is_valid_json { SELECT key, type, json_valid(value) AS is_json, fullkey, path FROM json_each('{"o":{"x":5},"a":[7,8]}') ORDER BY key; } { {a|array|1|$.a|$} {o|object|1|$.o|$} } do_execsql_test json_each_objects_empty_container_yields_zero_rows { SELECT COUNT(*) FROM json_each('{}'); } {0} do_execsql_test json_each_objects_keys_require_quoting_in_json_path { SELECT key, fullkey FROM json_each('{"a space":1,"a.b":2,"\"q\"":3, "_c": 4}') ORDER BY key DESC; } { {a.b|$."a.b"} {a space|$."a space"} {_c|$."_c"} {"q"|$."\"q\""} } do_execsql_test json_each_top_level_integer_single_row_key_null { SELECT (key IS NULL), fullkey, path, atom, type FROM json_each('42'); } {1|$|$|42|integer} do_execsql_test json_each_top_level_true_single_row_key_null { SELECT (key IS NULL), fullkey, path, atom, type FROM json_each('true'); } {1|$|$|1|true} do_execsql_test json_each_top_level_null_single_row_key_null { SELECT (key IS NULL), fullkey, path, (atom IS NULL), type FROM json_each('null'); } {1|$|$|1|null} do_execsql_test json_each_atom_equals_value_for_primitives_containers_are_json_text { WITH t AS ( SELECT * FROM json_each('[1,"x",{"y":2},[3]]') ) SELECT SUM(type IN ('object','array') AND json_valid(value)=1), SUM(type NOT IN ('object','array') AND value=atom) FROM t; } {2|2} do_execsql_test json_each_typeof_key_array_indices_integer { SELECT GROUP_CONCAT(ktype,'|') FROM ( SELECT typeof(key) AS ktype FROM json_each('[0,1]') ORDER BY key ); } {integer|integer} do_execsql_test json_each_typeof_key_object_keys_text { SELECT GROUP_CONCAT(ktype,'|') FROM ( SELECT typeof(key) AS ktype FROM json_each('{"0":0,"1":1}') ORDER BY key ); } {text|text} do_execsql_test json_each_parent_column_always_null { SELECT COUNT(*) FROM json_each('{"a":[1,2,3],"b":{}}') WHERE parent IS NOT NULL; } {0} do_execsql_test_error json_each_malformed_json_raises_error { SELECT * FROM json_each('{not json}'); } {(.*malformed JSON.*)} do_execsql_test json_each_object_member_order_preserved { SELECT key FROM json_each('{"z":0,"a":1,"m":2}'); } {z a m} do_execsql_test json_each_json_extract_on_value { SELECT key, json_extract(value, '$.x') FROM json_each('{"k1":{"x":11},"k2":{"x":22},"k3":{"x":[3]}}') WHERE type!='array' ORDER BY key; } { {k1|11} {k2|22} {k3|[3]} } do_execsql_test json-each-2arg-array-basic { SELECT key, value, type, path, fullkey FROM json_each('{"a":[1,2,3]}', '$.a') ORDER BY key; } { {0|1|integer|$.a|$.a[0]} {1|2|integer|$.a|$.a[1]} {2|3|integer|$.a|$.a[2]} } do_execsql_test json-each-2arg-object-basic { SELECT key, value, type, path, fullkey FROM json_each('{"obj":{"a":[1,2],"n":10,"x":"y"}}', '$.obj') ORDER BY key; } { {a|[1,2]|array|$.obj|$.obj.a} {n|10|integer|$.obj|$.obj.n} {x|y|text|$.obj|$.obj.x} } do_execsql_test json-each-2arg-root-dollar-array { SELECT key, value, type FROM json_each('[4,5]', '$') ORDER BY key; } { {0|4|integer} {1|5|integer} } do_execsql_test json-each-2arg-start-at-primitive { SELECT value, type, path, fullkey FROM json_each('{"a":[1,2,3]}', '$.a[1]'); } { {2|integer|$.a[1]|$.a[1]} } do_execsql_test json-each-2arg-start-at-object-inside-array { SELECT key, value, type, path, fullkey FROM json_each('{"arr":[{"x":1},{"y":2}]}', '$.arr[1]'); } { {y|2|integer|$.arr[1]|$.arr[1].y} } do_execsql_test json-each-2arg-nonexistent-path-returns-no-rows { SELECT count(*) FROM json_each('{"a":1}', '$.missing'); } {{0}} do_execsql_test json-each-2arg-empty-array { SELECT count(*) FROM json_each('{"a":[]}', '$.a'); } {{0}} do_execsql_test json-each-2arg-empty-object { SELECT count(*) FROM json_each('{"o":{}}', '$.o'); } {{0}} do_execsql_test json-each-2arg-bools-and-null { SELECT typeof(value), type FROM json_each('{"a":[null,true,false]}', '$.a') ORDER BY key; } { {null|null} {integer|true} {integer|false} } do_execsql_test json-each-2arg-primitive-key-null { SELECT typeof(key), value, type, path, fullkey FROM json_each('{"s":"hi"}', '$.s'); } {{null|hi|text|$.s|$.s}} do_execsql_test json-each-2arg-negative-index-root { SELECT key, value, type FROM json_each('[{"a":1},{"b":2},{"c":3}]', '$[#-1]'); } {{c|3|integer}} do_execsql_test_in_memory_any_error non-string-path { SELECT * FROM json_each('{}', 123); } do_execsql_test_in_memory_any_error invalid-path { SELECT * FROM json_each('{}', '$$$'); } do_execsql_test json-each-no-arguments { SELECT * FROM json_each(); } {} do_execsql_test_error json_each_3_arguments { SELECT * FROM json_each(1, 2, 3); } {.*(t|T)oo many arguments (for|on) json_each.*} do_execsql_test json-tree-1arg-root-object-and-children-preorder { SELECT key, type, fullkey, path FROM json_tree('{"a":1,"b":{"c":2},"d":[3,4]}') ORDER BY id; } { {|object|$|$} {a|integer|$.a|$} {b|object|$.b|$} {c|integer|$.b.c|$.b} {d|array|$.d|$} {0|integer|$.d[0]|$.d} {1|integer|$.d[1]|$.d} } do_execsql_test json-tree-1arg-root-array-and-children-preorder { SELECT key, type, fullkey, path FROM json_tree('[null,1,"two",{"three":4.5}]') ORDER BY id; } { {|array|$|$} {0|null|$[0]|$} {1|integer|$[1]|$} {2|text|$[2]|$} {3|object|$[3]|$} {three|real|$[3].three|$[3]} } do_execsql_test json-tree-1arg-primitive-root-null-single-row { SELECT typeof(key), typeof(value), type, fullkey, path FROM json_tree('null'); } {{null|null|null|$|$}} do_execsql_test json-tree-1arg-primitive-root-true-single-row { SELECT typeof(key), value, type, atom, fullkey, path FROM json_tree('true'); } {{null|1|true|1|$|$}} do_execsql_test json-tree-1arg-primitive-root-false-single-row { SELECT typeof(key), value, type, atom, fullkey, path FROM json_tree('false'); } {{null|0|false|0|$|$}} do_execsql_test json-tree-1arg-primitive-root-integer-single-row { SELECT typeof(key), value, type, atom, fullkey, path FROM json_tree('42'); } {{null|42|integer|42|$|$}} do_execsql_test json-tree-1arg-primitive-root-real-single-row { SELECT typeof(key), value, type, atom, fullkey, path FROM json_tree('3.14'); } {{null|3.14|real|3.14|$|$}} do_execsql_test json-tree-1arg-primitive-root-text-single-row { SELECT typeof(key), value, type, atom, fullkey, path FROM json_tree('"hi"'); } {{null|hi|text|hi|$|$}} do_execsql_test json-tree-atom-null-for-containers { SELECT type, typeof(atom) FROM json_tree('{"x":[1,2]}') WHERE type IN ('object','array') ORDER BY fullkey; } { {object|null} {array|null} } do_execsql_test json-tree-value-minified-for-containers { SELECT fullkey, value FROM json_tree('{"o":{"x":1,"y":2},"a":[1,2]}') WHERE type IN ('object','array') ORDER BY fullkey; } { {$|{"o":{"x":1,"y":2},"a":[1,2]}} {$.a|[1,2]} {$.o|{"x":1,"y":2}} } do_execsql_test json-tree-key-types-by-parent-kind { SELECT fullkey, typeof(key) FROM json_tree('{"o":{"x":1},"a":[10]}') WHERE fullkey IN ('$.o','$.o.x','$.a','$.a[0]') ORDER BY fullkey; } { {$.a|text} {$.a[0]|integer} {$.o|text} {$.o.x|text} } # TODO When {} is fixed, this can be reverted to a simpler # and more reliable version: # WITH t AS (SELECT * FROM json_tree('{"a":[1]}')) # SELECT c.fullkey, p.fullkey # FROM t AS c JOIN t AS p # ON c.parent = p.id # WHERE c.fullkey IN ('$.a','$.a[0]') # ORDER BY c.fullkey; do_execsql_test json-tree-parent-links-self-join { WITH c AS (SELECT * FROM json_tree('{"a":[1]}')), p AS (SELECT * FROM json_tree('{"a":[1]}')) SELECT c.fullkey, p.fullkey FROM c JOIN p ON c.parent = p.id WHERE c.fullkey IN ('$.a','$.a[0]') ORDER BY c.fullkey; } { {$.a|$} {$.a[0]|$.a} } do_execsql_test json-tree-parent-null-at-top { SELECT typeof(parent), fullkey FROM json_tree('{"k":1}') WHERE fullkey='$'; } {{null|$}} do_execsql_test json-tree-2arg-start-at-object { SELECT key, type, path, fullkey FROM json_tree('{"obj":{"x":1,"y":2}}', '$.obj') ORDER BY id; } { {obj|object|$|$.obj} {x|integer|$.obj|$.obj.x} {y|integer|$.obj|$.obj.y} } do_execsql_test json-tree-2arg-start-at-array { SELECT key, type, path, fullkey FROM json_tree('{"arr":[10,20]}', '$.arr') ORDER BY id; } { {arr|array|$|$.arr} {0|integer|$.arr|$.arr[0]} {1|integer|$.arr|$.arr[1]} } do_execsql_test json-tree-2arg-start-at-primitive-yields-single-row-and-path-to-self { SELECT typeof(key), value, type, path, fullkey FROM json_tree('{"a":5}', '$.a'); } {{text|5|integer|$|$.a}} do_execsql_test json-tree-2arg-nonexistent-path-returns-no-rows { SELECT count(*) FROM json_tree('{"a":1}', '$.missing'); } {{0}} do_execsql_test json-tree-2arg-empty-array { SELECT count(*) FROM json_tree('{"a":[]}', '$.a'); } {{1}} do_execsql_test json-tree-2arg-empty-object { SELECT count(*) FROM json_tree('{"o":{}}', '$.o'); } {{1}} do_execsql_test json-tree-2arg-bools-and-null-under-array { SELECT typeof(value), type FROM json_tree('{"a":[null,true,false]}', '$.a') WHERE fullkey != '$.a' ORDER BY key; } { {null|null} {integer|true} {integer|false} } do_execsql_test json-tree-fullkey-remains-absolute-under-subpath { SELECT DISTINCT substr(fullkey,1,4) FROM json_tree('{"x":{"y":1}}', '$.x'); } { {$.x} {$.x.} } do_execsql_test json-tree-path-points-to-container { SELECT fullkey, path FROM json_tree('{"x":[{"y":1}]}') WHERE fullkey IN ('$.x','$.x[0]','$.x[0].y') ORDER BY id; } { {$.x|$} {$.x[0]|$.x} {$.x[0].y|$.x[0]} } do_execsql_test json-tree-count-includes-containers-and-leaves { SELECT count(*) FROM json_tree('{"a":[1,2,3],"b":{"c":4}}'); } {{7}} do_execsql_test json-tree-escapes-in-fullkey { SELECT fullkey, value FROM json_tree('{"a.b":{"c d":1, "e_f": 2, "g\"h": 3}}') } { {$|{"a.b":{"c d":1,"e_f":2,"g\"h":3}}} {$."a.b"|{"c d":1,"e_f":2,"g\"h":3}} {$."a.b"."c d"|1} {$."a.b"."e_f"|2} {$."a.b"."g\"h"|3} } do_execsql_test json-tree-deeply-nested-mixed-types { SELECT type FROM json_tree('{"o":{"a":[1,{"b":[null,2.5]}]}}') ORDER BY id; } {object object array integer object array null real} do_execsql_test json-tree-ordering-by-fullkey-stable-hierarchy { SELECT fullkey FROM json_tree('{"z":0,"a":{"b":1,"a":2}}') ORDER BY fullkey; } { {$} {$.a} {$.a.a} {$.a.b} {$.z} } do_execsql_test json-tree-type-spectrum { SELECT type FROM json_tree('{"n":null,"t":true,"f":false,"i":1,"r":1.25,"s":"x","a":[],"o":{}}') WHERE fullkey != '$' ORDER BY fullkey; } {array false integer null object real text true} do_execsql_test json-tree-key-null-at-root { SELECT typeof(key), fullkey FROM json_tree('{"a":1}'); } { {null|$} {text|$.a} } do_execsql_test json-tree-key-integer-for-array-elements { SELECT typeof(key) FROM json_tree('[10,20]') WHERE fullkey IN ('$[0]','$[1]') ORDER BY key; } {integer integer} do_execsql_test json-tree-key-text-for-object-entries { SELECT typeof(key) FROM json_tree('{"x":1,"y":2}') WHERE fullkey IN ('$.x','$.y') ORDER BY key; } {text text} do_execsql_test json-tree-id-uniqueness { SELECT count(DISTINCT id)=count(*) FROM json_tree('{"a":[1,2],"b":3}'); } {{1}} do_execsql_test_in_memory_any_error json-tree-non-string-path { SELECT * FROM json_tree('{}', 123); } do_execsql_test_in_memory_any_error json-tree-invalid-path { SELECT * FROM json_tree('{}', '$$$'); } do_execsql_test json-tree-no-arguments { SELECT * FROM json_tree(); } {} do_execsql_test_error json_tree_3_arguments { SELECT * FROM json_tree(1, 2, 3); } {.*(t|T)oo many arguments (for|on) json_tree.*} # TODO these tests are disabled because negative indices # are buggy with json_tree in SQLite. Uncomment them and # implement the correct behaviour when # https://www.sqlite.org/forum/forumpost/48f5763d8c is addressed. # do_execsql_test json-tree-2arg-negative-index-root-array-element { # SELECT key, value, type, fullkey, path # FROM json_tree('[{"a":1},{"b":2},{"c":3}]', '$[#-1]') # ORDER BY id; # } { # {0|{"c":3}|object|$[#-1]|$} # {c|3|integer|$[#-1].c|$[#-1]} # } # do_execsql_test json-tree-2arg-negative-index-inside { # SELECT key, value, type, fullkey # FROM json_tree('{"arr":[0,1,2]}', '$.arr[#-2]'); # } { # {arr[#-2]|1|integer|$.arr[#-2]} # } # TODO add key and path columns back when # https://www.sqlite.org/forum/forumpost/48f5763d8c is addressed. do_execsql_test json-tree-nested-object { select fullkey, j.value from generate_series(0,2) s join json_tree('{"a": [1,2,3]}', '$.a[' || s.value || ']') j; } { {$.a[0]|1} {$.a[1]|2} {$.a[2]|3} }