1-- Strings.
2SELECT '""'::jsonb;				-- OK.
3SELECT $$''$$::jsonb;			-- ERROR, single quotes are not allowed
4SELECT '"abc"'::jsonb;			-- OK
5SELECT '"abc'::jsonb;			-- ERROR, quotes not closed
6SELECT '"abc
7def"'::jsonb;					-- ERROR, unescaped newline in string constant
8SELECT '"\n\"\\"'::jsonb;		-- OK, legal escapes
9SELECT '"\v"'::jsonb;			-- ERROR, not a valid JSON escape
10-- see json_encoding test for input with unicode escapes
11
12-- Numbers.
13SELECT '1'::jsonb;				-- OK
14SELECT '0'::jsonb;				-- OK
15SELECT '01'::jsonb;				-- ERROR, not valid according to JSON spec
16SELECT '0.1'::jsonb;				-- OK
17SELECT '9223372036854775808'::jsonb;	-- OK, even though it's too large for int8
18SELECT '1e100'::jsonb;			-- OK
19SELECT '1.3e100'::jsonb;			-- OK
20SELECT '1f2'::jsonb;				-- ERROR
21SELECT '0.x1'::jsonb;			-- ERROR
22SELECT '1.3ex100'::jsonb;		-- ERROR
23
24-- Arrays.
25SELECT '[]'::jsonb;				-- OK
26SELECT '[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]'::jsonb;  -- OK
27SELECT '[1,2]'::jsonb;			-- OK
28SELECT '[1,2,]'::jsonb;			-- ERROR, trailing comma
29SELECT '[1,2'::jsonb;			-- ERROR, no closing bracket
30SELECT '[1,[2]'::jsonb;			-- ERROR, no closing bracket
31
32-- Objects.
33SELECT '{}'::jsonb;				-- OK
34SELECT '{"abc"}'::jsonb;			-- ERROR, no value
35SELECT '{"abc":1}'::jsonb;		-- OK
36SELECT '{1:"abc"}'::jsonb;		-- ERROR, keys must be strings
37SELECT '{"abc",1}'::jsonb;		-- ERROR, wrong separator
38SELECT '{"abc"=1}'::jsonb;		-- ERROR, totally wrong separator
39SELECT '{"abc"::1}'::jsonb;		-- ERROR, another wrong separator
40SELECT '{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}'::jsonb; -- OK
41SELECT '{"abc":1:2}'::jsonb;		-- ERROR, colon in wrong spot
42SELECT '{"abc":1,3}'::jsonb;		-- ERROR, no value
43
44-- Recursion.
45SET max_stack_depth = '100kB';
46SELECT repeat('[', 10000)::jsonb;
47SELECT repeat('{"a":', 10000)::jsonb;
48RESET max_stack_depth;
49
50-- Miscellaneous stuff.
51SELECT 'true'::jsonb;			-- OK
52SELECT 'false'::jsonb;			-- OK
53SELECT 'null'::jsonb;			-- OK
54SELECT ' true '::jsonb;			-- OK, even with extra whitespace
55SELECT 'true false'::jsonb;		-- ERROR, too many values
56SELECT 'true, false'::jsonb;		-- ERROR, too many values
57SELECT 'truf'::jsonb;			-- ERROR, not a keyword
58SELECT 'trues'::jsonb;			-- ERROR, not a keyword
59SELECT ''::jsonb;				-- ERROR, no value
60SELECT '    '::jsonb;			-- ERROR, no value
61
62-- make sure jsonb is passed through json generators without being escaped
63SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
64
65-- anyarray column
66
67select to_jsonb(histogram_bounds) histogram_bounds
68from pg_stats
69where attname = 'tmplname' and tablename = 'pg_pltemplate';
70
71-- to_jsonb, timestamps
72
73select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
74
75BEGIN;
76SET LOCAL TIME ZONE 10.5;
77select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
78SET LOCAL TIME ZONE -8;
79select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
80COMMIT;
81
82select to_jsonb(date '2014-05-28');
83
84select to_jsonb(date 'Infinity');
85select to_jsonb(date '-Infinity');
86select to_jsonb(timestamp 'Infinity');
87select to_jsonb(timestamp '-Infinity');
88select to_jsonb(timestamptz 'Infinity');
89select to_jsonb(timestamptz '-Infinity');
90
91--jsonb_agg
92
93CREATE TEMP TABLE rows AS
94SELECT x, 'txt' || x as y
95FROM generate_series(1,3) AS x;
96
97SELECT jsonb_agg(q)
98  FROM ( SELECT $$a$$ || x AS b, y AS c,
99               ARRAY[ROW(x.*,ARRAY[1,2,3]),
100               ROW(y.*,ARRAY[4,5,6])] AS z
101         FROM generate_series(1,2) x,
102              generate_series(4,5) y) q;
103
104SELECT jsonb_agg(q ORDER BY x, y)
105  FROM rows q;
106
107UPDATE rows SET x = NULL WHERE x = 1;
108
109SELECT jsonb_agg(q ORDER BY x NULLS FIRST, y)
110  FROM rows q;
111
112-- jsonb extraction functions
113CREATE TEMP TABLE test_jsonb (
114       json_type text,
115       test_json jsonb
116);
117
118INSERT INTO test_jsonb VALUES
119('scalar','"a scalar"'),
120('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
121('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
122
123SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'scalar';
124SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'array';
125SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'object';
126SELECT test_json -> 'field2' FROM test_jsonb WHERE json_type = 'object';
127
128SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'scalar';
129SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'array';
130SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'object';
131
132SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'scalar';
133SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'array';
134SELECT test_json -> 9 FROM test_jsonb WHERE json_type = 'array';
135SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'object';
136
137SELECT test_json ->> 6 FROM test_jsonb WHERE json_type = 'array';
138SELECT test_json ->> 7 FROM test_jsonb WHERE json_type = 'array';
139
140SELECT test_json ->> 'field4' FROM test_jsonb WHERE json_type = 'object';
141SELECT test_json ->> 'field5' FROM test_jsonb WHERE json_type = 'object';
142SELECT test_json ->> 'field6' FROM test_jsonb WHERE json_type = 'object';
143
144SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'scalar';
145SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'array';
146SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'object';
147
148SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'scalar';
149SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'array';
150SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'object';
151
152-- nulls
153SELECT (test_json->'field3') IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'object';
154SELECT (test_json->>'field3') IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'object';
155SELECT (test_json->3) IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'array';
156SELECT (test_json->>3) IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'array';
157
158-- corner cases
159select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::text;
160select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::int;
161select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 1;
162select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 'z';
163select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> '';
164select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 1;
165select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 3;
166select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 'z';
167select '{"a": "c", "b": null}'::jsonb -> 'b';
168select '"foo"'::jsonb -> 1;
169select '"foo"'::jsonb -> 'z';
170
171select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::text;
172select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::int;
173select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 1;
174select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 'z';
175select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> '';
176select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 1;
177select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 3;
178select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 'z';
179select '{"a": "c", "b": null}'::jsonb ->> 'b';
180select '"foo"'::jsonb ->> 1;
181select '"foo"'::jsonb ->> 'z';
182
183-- equality and inequality
184SELECT '{"x":"y"}'::jsonb = '{"x":"y"}'::jsonb;
185SELECT '{"x":"y"}'::jsonb = '{"x":"z"}'::jsonb;
186
187SELECT '{"x":"y"}'::jsonb <> '{"x":"y"}'::jsonb;
188SELECT '{"x":"y"}'::jsonb <> '{"x":"z"}'::jsonb;
189
190-- containment
191SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
192SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":null}');
193SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "g":null}');
194SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"g":null}');
195SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"c"}');
196SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
197SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":"q"}');
198SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
199SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":null}';
200SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "g":null}';
201SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"g":null}';
202SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"c"}';
203SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
204SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":"q"}';
205
206SELECT '[1,2]'::jsonb @> '[1,2,2]'::jsonb;
207SELECT '[1,1,2]'::jsonb @> '[1,2,2]'::jsonb;
208SELECT '[[1,2]]'::jsonb @> '[[1,2,2]]'::jsonb;
209SELECT '[1,2,2]'::jsonb <@ '[1,2]'::jsonb;
210SELECT '[1,2,2]'::jsonb <@ '[1,1,2]'::jsonb;
211SELECT '[[1,2,2]]'::jsonb <@ '[[1,2]]'::jsonb;
212
213SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
214SELECT jsonb_contained('{"a":"b", "c":null}', '{"a":"b", "b":1, "c":null}');
215SELECT jsonb_contained('{"a":"b", "g":null}', '{"a":"b", "b":1, "c":null}');
216SELECT jsonb_contained('{"g":null}', '{"a":"b", "b":1, "c":null}');
217SELECT jsonb_contained('{"a":"c"}', '{"a":"b", "b":1, "c":null}');
218SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
219SELECT jsonb_contained('{"a":"b", "c":"q"}', '{"a":"b", "b":1, "c":null}');
220SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
221SELECT '{"a":"b", "c":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
222SELECT '{"a":"b", "g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
223SELECT '{"g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
224SELECT '{"a":"c"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
225SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
226SELECT '{"a":"b", "c":"q"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
227-- Raw scalar may contain another raw scalar, array may contain a raw scalar
228SELECT '[5]'::jsonb @> '[5]';
229SELECT '5'::jsonb @> '5';
230SELECT '[5]'::jsonb @> '5';
231-- But a raw scalar cannot contain an array
232SELECT '5'::jsonb @> '[5]';
233-- In general, one thing should always contain itself. Test array containment:
234SELECT '["9", ["7", "3"], 1]'::jsonb @> '["9", ["7", "3"], 1]'::jsonb;
235SELECT '["9", ["7", "3"], ["1"]]'::jsonb @> '["9", ["7", "3"], ["1"]]'::jsonb;
236-- array containment string matching confusion bug
237SELECT '{ "name": "Bob", "tags": [ "enim", "qui"]}'::jsonb @> '{"tags":["qu"]}';
238
239-- array length
240SELECT jsonb_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
241SELECT jsonb_array_length('[]');
242SELECT jsonb_array_length('{"f1":1,"f2":[5,6]}');
243SELECT jsonb_array_length('4');
244
245-- each
246SELECT jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
247SELECT jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
248SELECT * FROM jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
249SELECT * FROM jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
250
251SELECT jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
252SELECT jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
253SELECT * FROM jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
254SELECT * FROM jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
255
256-- exists
257SELECT jsonb_exists('{"a":null, "b":"qq"}', 'a');
258SELECT jsonb_exists('{"a":null, "b":"qq"}', 'b');
259SELECT jsonb_exists('{"a":null, "b":"qq"}', 'c');
260SELECT jsonb_exists('{"a":"null", "b":"qq"}', 'a');
261SELECT jsonb '{"a":null, "b":"qq"}' ? 'a';
262SELECT jsonb '{"a":null, "b":"qq"}' ? 'b';
263SELECT jsonb '{"a":null, "b":"qq"}' ? 'c';
264SELECT jsonb '{"a":"null", "b":"qq"}' ? 'a';
265-- array exists - array elements should behave as keys
266SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
267-- type sensitive array exists - should return no rows (since "exists" only
268-- matches strings that are either object keys or array elements)
269SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
270-- However, a raw scalar is *contained* within the array
271SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
272
273SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['a','b']);
274SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['b','a']);
275SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','a']);
276SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','d']);
277SELECT jsonb_exists_any('{"a":null, "b":"qq"}', '{}'::text[]);
278SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['a','b'];
279SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['b','a'];
280SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','a'];
281SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','d'];
282SELECT jsonb '{"a":null, "b":"qq"}' ?| '{}'::text[];
283
284SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['a','b']);
285SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['b','a']);
286SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','a']);
287SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','d']);
288SELECT jsonb_exists_all('{"a":null, "b":"qq"}', '{}'::text[]);
289SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','b'];
290SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['b','a'];
291SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','a'];
292SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','d'];
293SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','a', 'b', 'b', 'b'];
294SELECT jsonb '{"a":null, "b":"qq"}' ?& '{}'::text[];
295
296-- typeof
297SELECT jsonb_typeof('{}') AS object;
298SELECT jsonb_typeof('{"c":3,"p":"o"}') AS object;
299SELECT jsonb_typeof('[]') AS array;
300SELECT jsonb_typeof('["a", 1]') AS array;
301SELECT jsonb_typeof('null') AS "null";
302SELECT jsonb_typeof('1') AS number;
303SELECT jsonb_typeof('-1') AS number;
304SELECT jsonb_typeof('1.0') AS number;
305SELECT jsonb_typeof('1e2') AS number;
306SELECT jsonb_typeof('-1.0') AS number;
307SELECT jsonb_typeof('true') AS boolean;
308SELECT jsonb_typeof('false') AS boolean;
309SELECT jsonb_typeof('"hello"') AS string;
310SELECT jsonb_typeof('"true"') AS string;
311SELECT jsonb_typeof('"1.0"') AS string;
312
313-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
314
315SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
316SELECT jsonb_build_array('a', NULL); -- ok
317SELECT jsonb_build_array(VARIADIC NULL::text[]); -- ok
318SELECT jsonb_build_array(VARIADIC '{}'::text[]); -- ok
319SELECT jsonb_build_array(VARIADIC '{a,b,c}'::text[]); -- ok
320SELECT jsonb_build_array(VARIADIC ARRAY['a', NULL]::text[]); -- ok
321SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::text[]); -- ok
322SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::int[]); -- ok
323SELECT jsonb_build_array(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
324
325SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
326
327SELECT jsonb_build_object(
328       'a', jsonb_build_object('b',false,'c',99),
329       'd', jsonb_build_object('e',array[9,8,7]::int[],
330           'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
331SELECT jsonb_build_object('{a,b,c}'::text[]); -- error
332SELECT jsonb_build_object('{a,b,c}'::text[], '{d,e,f}'::text[]); -- error, key cannot be array
333SELECT jsonb_build_object('a', 'b', 'c'); -- error
334SELECT jsonb_build_object(NULL, 'a'); -- error, key cannot be NULL
335SELECT jsonb_build_object('a', NULL); -- ok
336SELECT jsonb_build_object(VARIADIC NULL::text[]); -- ok
337SELECT jsonb_build_object(VARIADIC '{}'::text[]); -- ok
338SELECT jsonb_build_object(VARIADIC '{a,b,c}'::text[]); -- error
339SELECT jsonb_build_object(VARIADIC ARRAY['a', NULL]::text[]); -- ok
340SELECT jsonb_build_object(VARIADIC ARRAY[NULL, 'a']::text[]); -- error, key cannot be NULL
341SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::text[]); -- ok
342SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::int[]); -- ok
343SELECT jsonb_build_object(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
344
345-- empty objects/arrays
346SELECT jsonb_build_array();
347
348SELECT jsonb_build_object();
349
350-- make sure keys are quoted
351SELECT jsonb_build_object(1,2);
352
353-- keys must be scalar and not null
354SELECT jsonb_build_object(null,2);
355
356SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
357
358SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
359
360SELECT jsonb_build_object('{1,2,3}'::int[], 3);
361
362-- handling of NULL values
363SELECT jsonb_object_agg(1, NULL::jsonb);
364SELECT jsonb_object_agg(NULL, '{"a":1}');
365
366CREATE TEMP TABLE foo (serial_num int, name text, type text);
367INSERT INTO foo VALUES (847001,'t15','GE1043');
368INSERT INTO foo VALUES (847002,'t16','GE1043');
369INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
370
371SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
372FROM foo;
373
374SELECT jsonb_object_agg(name, type) FROM foo;
375
376INSERT INTO foo VALUES (999999, NULL, 'bar');
377SELECT jsonb_object_agg(name, type) FROM foo;
378
379-- jsonb_object
380
381-- empty object, one dimension
382SELECT jsonb_object('{}');
383
384-- empty object, two dimensions
385SELECT jsonb_object('{}', '{}');
386
387-- one dimension
388SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
389
390-- same but with two dimensions
391SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
392
393-- odd number error
394SELECT jsonb_object('{a,b,c}');
395
396-- one column error
397SELECT jsonb_object('{{a},{b}}');
398
399-- too many columns error
400SELECT jsonb_object('{{a,b,c},{b,c,d}}');
401
402-- too many dimensions error
403SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
404
405--two argument form of jsonb_object
406
407select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
408
409-- too many dimensions
410SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}', '{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
411
412-- mismatched dimensions
413
414select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
415
416select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
417
418-- null key error
419
420select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
421
422-- empty key is allowed
423
424select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
425
426
427
428-- extract_path, extract_path_as_text
429SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
430SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
431SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
432SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
433SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
434SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
435SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
436SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
437
438-- extract_path nulls
439SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_false;
440SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_true;
441SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_false;
442SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_true;
443
444-- extract_path operators
445SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f4','f6'];
446SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2'];
447SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','0'];
448SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','1'];
449
450SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f4','f6'];
451SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2'];
452SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','0'];
453SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','1'];
454
455-- corner cases for same
456select '{"a": {"b":{"c": "foo"}}}'::jsonb #> '{}';
457select '[1,2,3]'::jsonb #> '{}';
458select '"foo"'::jsonb #> '{}';
459select '42'::jsonb #> '{}';
460select 'null'::jsonb #> '{}';
461select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a'];
462select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a', null];
463select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a', ''];
464select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b'];
465select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b','c'];
466select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b','c','d'];
467select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','z','c'];
468select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #> array['a','1','b'];
469select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #> array['a','z','b'];
470select '[{"b": "c"}, {"b": "cc"}]'::jsonb #> array['1','b'];
471select '[{"b": "c"}, {"b": "cc"}]'::jsonb #> array['z','b'];
472select '[{"b": "c"}, {"b": null}]'::jsonb #> array['1','b'];
473select '"foo"'::jsonb #> array['z'];
474select '42'::jsonb #> array['f2'];
475select '42'::jsonb #> array['0'];
476
477select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> '{}';
478select '[1,2,3]'::jsonb #>> '{}';
479select '"foo"'::jsonb #>> '{}';
480select '42'::jsonb #>> '{}';
481select 'null'::jsonb #>> '{}';
482select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a'];
483select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', null];
484select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', ''];
485select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b'];
486select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c'];
487select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c','d'];
488select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','z','c'];
489select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','1','b'];
490select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','z','b'];
491select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['1','b'];
492select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['z','b'];
493select '[{"b": "c"}, {"b": null}]'::jsonb #>> array['1','b'];
494select '"foo"'::jsonb #>> array['z'];
495select '42'::jsonb #>> array['f2'];
496select '42'::jsonb #>> array['0'];
497
498-- array_elements
499SELECT jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
500SELECT * FROM jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
501SELECT jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
502SELECT * FROM jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
503
504-- populate_record
505CREATE TYPE jbpop AS (a text, b int, c timestamp);
506
507CREATE DOMAIN jsb_int_not_null  AS int     NOT NULL;
508CREATE DOMAIN jsb_int_array_1d  AS int[]   CHECK(array_length(VALUE, 1) = 3);
509CREATE DOMAIN jsb_int_array_2d  AS int[][] CHECK(array_length(VALUE, 2) = 3);
510
511create type jb_unordered_pair as (x int, y int);
512create domain jb_ordered_pair as jb_unordered_pair check((value).x <= (value).y);
513
514CREATE TYPE jsbrec AS (
515	i	int,
516	ia	_int4,
517	ia1	int[],
518	ia2	int[][],
519	ia3	int[][][],
520	ia1d	jsb_int_array_1d,
521	ia2d	jsb_int_array_2d,
522	t	text,
523	ta	text[],
524	c	char(10),
525	ca	char(10)[],
526	ts	timestamp,
527	js	json,
528	jsb	jsonb,
529	jsa	json[],
530	rec	jbpop,
531	reca	jbpop[]
532);
533
534CREATE TYPE jsbrec_i_not_null AS (
535	i	jsb_int_not_null
536);
537
538SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
539SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
540
541SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
542SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
543
544SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":[100,200,false],"x":43.2}') q;
545SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":[100,200,false],"x":43.2}') q;
546SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"c":[100,200,false],"x":43.2}') q;
547
548SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop, '{}') q;
549
550SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"x": 43.2}') q;
551SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"i": null}') q;
552SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"i": 12345}') q;
553
554SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": null}') q;
555SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": 123}') q;
556SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [1, "2", null, 4]}') q;
557SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1, 2], [3, 4]]}') q;
558SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1], 2]}') q;
559SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1], [2, 3]]}') q;
560SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": "{1,2,3}"}') q;
561
562SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": null}') q;
563SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": 123}') q;
564SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": [1, "2", null, 4]}') q;
565SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": [[1, 2, 3]]}') q;
566
567SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": null}') q;
568SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": 123}') q;
569SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": [1, "2", null, 4]}') q;
570SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": [1, "2", null]}') q;
571
572SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [1, "2", null, 4]}') q;
573SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], [null, 4]]}') q;
574SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[], []]}') q;
575SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], [3]]}') q;
576SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], 3, 4]}') q;
577
578SELECT ia2d FROM jsonb_populate_record(NULL::jsbrec, '{"ia2d": [[1, "2"], [null, 4]]}') q;
579SELECT ia2d FROM jsonb_populate_record(NULL::jsbrec, '{"ia2d": [[1, "2", 3], [null, 5, 6]]}') q;
580
581SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [1, "2", null, 4]}') q;
582SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [[1, 2], [null, 4]]}') q;
583SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[], []], [[], []], [[], []] ]}') q;
584SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2]], [[3, 4]] ]}') q;
585SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2], [3, 4]], [[5, 6], [7, 8]] ]}') q;
586SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2], [3, 4]], [[5, 6], [7, 8], [9, 10]] ]}') q;
587
588SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": null}') q;
589SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": 123}') q;
590SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": [1, "2", null, 4]}') q;
591SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": [[1, 2, 3], {"k": "v"}]}') q;
592
593SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": null}') q;
594SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaa"}') q;
595SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaaaaaaaaa"}') q;
596SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaaaaaaaaaaaa"}') q;
597
598SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": null}') q;
599SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": 123}') q;
600SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": [1, "2", null, 4]}') q;
601SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": ["aaaaaaaaaaaaaaaa"]}') q;
602SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": [[1, 2, 3], {"k": "v"}]}') q;
603
604SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": null}') q;
605SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": true}') q;
606SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": 123.45}') q;
607SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": "123.45"}') q;
608SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": "abc"}') q;
609SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": [123, "123", null, {"key": "value"}]}') q;
610SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": {"a": "bbb", "b": null, "c": 123.45}}') q;
611
612SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": null}') q;
613SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": true}') q;
614SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": 123.45}') q;
615SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": "123.45"}') q;
616SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": "abc"}') q;
617SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": [123, "123", null, {"key": "value"}]}') q;
618SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": {"a": "bbb", "b": null, "c": 123.45}}') q;
619
620SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": null}') q;
621SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": 123}') q;
622SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": [1, "2", null, 4]}') q;
623SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": ["aaa", null, [1, 2, "3", {}], { "k" : "v" }]}') q;
624
625SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": 123}') q;
626SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": [1, 2]}') q;
627SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2}}') q;
628SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": "(abc,42,01.02.2003)"}') q;
629
630SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": 123}') q;
631SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": [1, 2]}') q;
632SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": [{"a": "abc", "b": 456}, null, {"c": "01.02.2003", "x": 43.2}]}') q;
633SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": ["(abc,42,01.02.2003)"]}') q;
634SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": "{\"(abc,42,01.02.2003)\"}"}') q;
635
636SELECT rec FROM jsonb_populate_record(
637	row(NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,
638		row('x',3,'2012-12-31 15:30:56')::jbpop,NULL)::jsbrec,
639	'{"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2}}'
640) q;
641
642-- anonymous record type
643SELECT jsonb_populate_record(null::record, '{"x": 0, "y": 1}');
644SELECT jsonb_populate_record(row(1,2), '{"f1": 0, "f2": 1}');
645SELECT * FROM
646  jsonb_populate_record(null::record, '{"x": 776}') AS (x int, y int);
647
648-- composite domain
649SELECT jsonb_populate_record(null::jb_ordered_pair, '{"x": 0, "y": 1}');
650SELECT jsonb_populate_record(row(1,2)::jb_ordered_pair, '{"x": 0}');
651SELECT jsonb_populate_record(row(1,2)::jb_ordered_pair, '{"x": 1, "y": 0}');
652
653-- populate_recordset
654SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
655SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
656SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
657SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
658SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
659SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
660
661SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
662SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
663SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
664
665-- anonymous record type
666SELECT jsonb_populate_recordset(null::record, '[{"x": 0, "y": 1}]');
667SELECT jsonb_populate_recordset(row(1,2), '[{"f1": 0, "f2": 1}]');
668SELECT i, jsonb_populate_recordset(row(i,50), '[{"f1":"42"},{"f2":"43"}]')
669FROM (VALUES (1),(2)) v(i);
670SELECT * FROM
671  jsonb_populate_recordset(null::record, '[{"x": 776}]') AS (x int, y int);
672
673-- empty array is a corner case
674SELECT jsonb_populate_recordset(null::record, '[]');
675SELECT jsonb_populate_recordset(row(1,2), '[]');
676SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[]') q;
677SELECT * FROM
678  jsonb_populate_recordset(null::record, '[]') AS (x int, y int);
679
680-- composite domain
681SELECT jsonb_populate_recordset(null::jb_ordered_pair, '[{"x": 0, "y": 1}]');
682SELECT jsonb_populate_recordset(row(1,2)::jb_ordered_pair, '[{"x": 0}, {"y": 3}]');
683SELECT jsonb_populate_recordset(row(1,2)::jb_ordered_pair, '[{"x": 1, "y": 0}]');
684
685-- negative cases where the wrong record type is supplied
686select * from jsonb_populate_recordset(row(0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
687select * from jsonb_populate_recordset(row(0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
688select * from jsonb_populate_recordset(row(0::int,0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
689select * from jsonb_populate_recordset(row(1000000000::int,50::int),'[{"b":"2"},{"a":"3"}]') q (a text, b text);
690
691-- jsonb_to_record and jsonb_to_recordset
692
693select * from jsonb_to_record('{"a":1,"b":"foo","c":"bar"}')
694    as x(a int, b text, d text);
695
696select * from jsonb_to_recordset('[{"a":1,"b":"foo","d":false},{"a":2,"b":"bar","c":true}]')
697    as x(a int, b text, c boolean);
698
699select *, c is null as c_is_null
700from jsonb_to_record('{"a":1, "b":{"c":16, "d":2}, "x":8, "ca": ["1 2", 3], "ia": [[1,2],[3,4]], "r": {"a": "aaa", "b": 123}}'::jsonb)
701    as t(a int, b jsonb, c text, x int, ca char(5)[], ia int[][], r jbpop);
702
703select *, c is null as c_is_null
704from jsonb_to_recordset('[{"a":1, "b":{"c":16, "d":2}, "x":8}]'::jsonb)
705    as t(a int, b jsonb, c text, x int);
706
707select * from jsonb_to_record('{"ia": null}') as x(ia _int4);
708select * from jsonb_to_record('{"ia": 123}') as x(ia _int4);
709select * from jsonb_to_record('{"ia": [1, "2", null, 4]}') as x(ia _int4);
710select * from jsonb_to_record('{"ia": [[1, 2], [3, 4]]}') as x(ia _int4);
711select * from jsonb_to_record('{"ia": [[1], 2]}') as x(ia _int4);
712select * from jsonb_to_record('{"ia": [[1], [2, 3]]}') as x(ia _int4);
713
714select * from jsonb_to_record('{"ia2": [1, 2, 3]}') as x(ia2 int[][]);
715select * from jsonb_to_record('{"ia2": [[1, 2], [3, 4]]}') as x(ia2 int4[][]);
716select * from jsonb_to_record('{"ia2": [[[1], [2], [3]]]}') as x(ia2 int4[][]);
717
718select * from jsonb_to_record('{"out": {"key": 1}}') as x(out json);
719select * from jsonb_to_record('{"out": [{"key": 1}]}') as x(out json);
720select * from jsonb_to_record('{"out": "{\"key\": 1}"}') as x(out json);
721select * from jsonb_to_record('{"out": {"key": 1}}') as x(out jsonb);
722select * from jsonb_to_record('{"out": [{"key": 1}]}') as x(out jsonb);
723select * from jsonb_to_record('{"out": "{\"key\": 1}"}') as x(out jsonb);
724
725-- test type info caching in jsonb_populate_record()
726CREATE TEMP TABLE jsbpoptest (js jsonb);
727
728INSERT INTO jsbpoptest
729SELECT '{
730	"jsa": [1, "2", null, 4],
731	"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2},
732	"reca": [{"a": "abc", "b": 456}, null, {"c": "01.02.2003", "x": 43.2}]
733}'::jsonb
734FROM generate_series(1, 3);
735
736SELECT (jsonb_populate_record(NULL::jsbrec, js)).* FROM jsbpoptest;
737
738DROP TYPE jsbrec;
739DROP TYPE jsbrec_i_not_null;
740DROP DOMAIN jsb_int_not_null;
741DROP DOMAIN jsb_int_array_1d;
742DROP DOMAIN jsb_int_array_2d;
743DROP DOMAIN jb_ordered_pair;
744DROP TYPE jb_unordered_pair;
745
746-- indexing
747SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
748SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
749SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
750SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
751SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
752SELECT count(*) FROM testjsonb WHERE j ? 'public';
753SELECT count(*) FROM testjsonb WHERE j ? 'bar';
754SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
755SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
756
757CREATE INDEX jidx ON testjsonb USING gin (j);
758SET enable_seqscan = off;
759
760SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
761SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
762SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
763SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
764SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
765SELECT count(*) FROM testjsonb WHERE j @> '{"array":["foo"]}';
766SELECT count(*) FROM testjsonb WHERE j @> '{"array":["bar"]}';
767-- exercise GIN_SEARCH_MODE_ALL
768SELECT count(*) FROM testjsonb WHERE j @> '{}';
769SELECT count(*) FROM testjsonb WHERE j ? 'public';
770SELECT count(*) FROM testjsonb WHERE j ? 'bar';
771SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
772SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
773
774-- array exists - array elements should behave as keys (for GIN index scans too)
775CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
776SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
777-- type sensitive array exists - should return no rows (since "exists" only
778-- matches strings that are either object keys or array elements)
779SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
780-- However, a raw scalar is *contained* within the array
781SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
782
783RESET enable_seqscan;
784
785SELECT count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow;
786SELECT key, count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow GROUP BY key ORDER BY count DESC, key;
787
788-- sort/hash
789SELECT count(distinct j) FROM testjsonb;
790SET enable_hashagg = off;
791SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
792SET enable_hashagg = on;
793SET enable_sort = off;
794SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
795SELECT distinct * FROM (values (jsonb '{}' || ''::text),('{}')) v(j);
796SET enable_sort = on;
797
798RESET enable_hashagg;
799RESET enable_sort;
800
801DROP INDEX jidx;
802DROP INDEX jidx_array;
803-- btree
804CREATE INDEX jidx ON testjsonb USING btree (j);
805SET enable_seqscan = off;
806
807SELECT count(*) FROM testjsonb WHERE j > '{"p":1}';
808SELECT count(*) FROM testjsonb WHERE j = '{"pos":98, "line":371, "node":"CBA", "indexed":true}';
809
810--gin path opclass
811DROP INDEX jidx;
812CREATE INDEX jidx ON testjsonb USING gin (j jsonb_path_ops);
813SET enable_seqscan = off;
814
815SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
816SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
817SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
818SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
819SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
820-- exercise GIN_SEARCH_MODE_ALL
821SELECT count(*) FROM testjsonb WHERE j @> '{}';
822
823RESET enable_seqscan;
824DROP INDEX jidx;
825
826-- nested tests
827SELECT '{"ff":{"a":12,"b":16}}'::jsonb;
828SELECT '{"ff":{"a":12,"b":16},"qq":123}'::jsonb;
829SELECT '{"aa":["a","aaa"],"qq":{"a":12,"b":16,"c":["c1","c2"],"d":{"d1":"d1","d2":"d2","d1":"d3"}}}'::jsonb;
830SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2"],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
831SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2",["c3"],{"c4":4}],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
832SELECT '{"ff":["a","aaa"]}'::jsonb;
833
834SELECT
835  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'ff',
836  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'qq',
837  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'Y') IS NULL AS f,
838  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb ->> 'Y') IS NULL AS t,
839   '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'x';
840
841-- nested containment
842SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1,2]}';
843SELECT '{"a":[2,1],"c":"b"}'::jsonb @> '{"a":[1,2]}';
844SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":[1,2]}';
845SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":[1,2]}';
846SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
847SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
848SELECT '["a","b"]'::jsonb @> '["a","b","c","b"]';
849SELECT '["a","b","c","b"]'::jsonb @> '["a","b"]';
850SELECT '["a","b","c",[1,2]]'::jsonb @> '["a",[1,2]]';
851SELECT '["a","b","c",[1,2]]'::jsonb @> '["b",[1,2]]';
852
853SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1]}';
854SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[2]}';
855SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[3]}';
856
857SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"c":3}]}';
858SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4}]}';
859SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},3]}';
860SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},1]}';
861
862-- check some corner cases for indexed nested containment (bug #13756)
863create temp table nestjsonb (j jsonb);
864insert into nestjsonb (j) values ('{"a":[["b",{"x":1}],["b",{"x":2}]],"c":3}');
865insert into nestjsonb (j) values ('[[14,2,3]]');
866insert into nestjsonb (j) values ('[1,[14,2,3]]');
867create index on nestjsonb using gin(j jsonb_path_ops);
868
869set enable_seqscan = on;
870set enable_bitmapscan = off;
871select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
872select * from nestjsonb where j @> '{"c":3}';
873select * from nestjsonb where j @> '[[14]]';
874set enable_seqscan = off;
875set enable_bitmapscan = on;
876select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
877select * from nestjsonb where j @> '{"c":3}';
878select * from nestjsonb where j @> '[[14]]';
879reset enable_seqscan;
880reset enable_bitmapscan;
881
882-- nested object field / array index lookup
883SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'n';
884SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'a';
885SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'b';
886SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'c';
887SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd';
888SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd' -> '1';
889SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'e';
890SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 0; --expecting error
891
892SELECT '["a","b","c",[1,2],null]'::jsonb -> 0;
893SELECT '["a","b","c",[1,2],null]'::jsonb -> 1;
894SELECT '["a","b","c",[1,2],null]'::jsonb -> 2;
895SELECT '["a","b","c",[1,2],null]'::jsonb -> 3;
896SELECT '["a","b","c",[1,2],null]'::jsonb -> 3 -> 1;
897SELECT '["a","b","c",[1,2],null]'::jsonb -> 4;
898SELECT '["a","b","c",[1,2],null]'::jsonb -> 5;
899SELECT '["a","b","c",[1,2],null]'::jsonb -> -1;
900SELECT '["a","b","c",[1,2],null]'::jsonb -> -5;
901SELECT '["a","b","c",[1,2],null]'::jsonb -> -6;
902
903--nested path extraction
904SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{0}';
905SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{a}';
906SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c}';
907SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,0}';
908SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,1}';
909SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,2}';
910SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,3}';
911SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-1}';
912SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-3}';
913SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-4}';
914
915SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{0}';
916SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{3}';
917SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4}';
918SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4,5}';
919
920--nested exists
921SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'n';
922SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'a';
923SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'b';
924SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'c';
925SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'd';
926SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'e';
927
928-- jsonb_strip_nulls
929
930select jsonb_strip_nulls(null);
931
932select jsonb_strip_nulls('1');
933
934select jsonb_strip_nulls('"a string"');
935
936select jsonb_strip_nulls('null');
937
938select jsonb_strip_nulls('[1,2,null,3,4]');
939
940select jsonb_strip_nulls('{"a":1,"b":null,"c":[2,null,3],"d":{"e":4,"f":null}}');
941
942select jsonb_strip_nulls('[1,{"a":1,"b":null,"c":2},3]');
943
944-- an empty object is not null and should not be stripped
945select jsonb_strip_nulls('{"a": {"b": null, "c": null}, "d": {} }');
946
947
948select jsonb_pretty('{"a": "test", "b": [1, 2, 3], "c": "test3", "d":{"dd": "test4", "dd2":{"ddd": "test5"}}}');
949select jsonb_pretty('[{"f1":1,"f2":null},2,null,[[{"x":true},6,7],8],3]');
950select jsonb_pretty('{"a":["b", "c"], "d": {"e":"f"}}');
951
952select jsonb_concat('{"d": "test", "a": [1, 2]}', '{"g": "test2", "c": {"c1":1, "c2":2}}');
953
954select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
955select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aq":"l"}';
956select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aa":"l"}';
957select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{}';
958
959select '["a", "b"]'::jsonb || '["c"]';
960select '["a", "b"]'::jsonb || '["c", "d"]';
961select '["c"]' || '["a", "b"]'::jsonb;
962
963select '["a", "b"]'::jsonb || '"c"';
964select '"c"' || '["a", "b"]'::jsonb;
965
966select '[]'::jsonb || '["a"]'::jsonb;
967select '[]'::jsonb || '"a"'::jsonb;
968select '"b"'::jsonb || '"a"'::jsonb;
969select '{}'::jsonb || '{"a":"b"}'::jsonb;
970select '[]'::jsonb || '{"a":"b"}'::jsonb;
971select '{"a":"b"}'::jsonb || '[]'::jsonb;
972
973select '"a"'::jsonb || '{"a":1}';
974select '{"a":1}' || '"a"'::jsonb;
975
976select '[3]'::jsonb || '{}'::jsonb;
977select '3'::jsonb || '[]'::jsonb;
978select '3'::jsonb || '4'::jsonb;
979select '3'::jsonb || '{}'::jsonb;
980
981select '["a", "b"]'::jsonb || '{"c":1}';
982select '{"c": 1}'::jsonb || '["a", "b"]';
983
984select '{}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
985
986select pg_column_size('{}'::jsonb || '{}'::jsonb) = pg_column_size('{}'::jsonb);
987select pg_column_size('{"aa":1}'::jsonb || '{"b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
988select pg_column_size('{"aa":1, "b":2}'::jsonb || '{}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
989select pg_column_size('{}'::jsonb || '{"aa":1, "b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
990
991select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'a');
992select jsonb_delete('{"a":null , "b":2, "c":3}'::jsonb, 'a');
993select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'b');
994select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'c');
995select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'd');
996select '{"a":1 , "b":2, "c":3}'::jsonb - 'a';
997select '{"a":null , "b":2, "c":3}'::jsonb - 'a';
998select '{"a":1 , "b":2, "c":3}'::jsonb - 'b';
999select '{"a":1 , "b":2, "c":3}'::jsonb - 'c';
1000select '{"a":1 , "b":2, "c":3}'::jsonb - 'd';
1001select pg_column_size('{"a":1 , "b":2, "c":3}'::jsonb - 'b') = pg_column_size('{"a":1, "b":2}'::jsonb);
1002
1003select '["a","b","c"]'::jsonb - 3;
1004select '["a","b","c"]'::jsonb - 2;
1005select '["a","b","c"]'::jsonb - 1;
1006select '["a","b","c"]'::jsonb - 0;
1007select '["a","b","c"]'::jsonb - -1;
1008select '["a","b","c"]'::jsonb - -2;
1009select '["a","b","c"]'::jsonb - -3;
1010select '["a","b","c"]'::jsonb - -4;
1011
1012select '{"a":1 , "b":2, "c":3}'::jsonb - '{b}'::text[];
1013select '{"a":1 , "b":2, "c":3}'::jsonb - '{c,b}'::text[];
1014select '{"a":1 , "b":2, "c":3}'::jsonb - '{}'::text[];
1015
1016select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '[1,2,3]');
1017select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '[1,2,3]');
1018select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '[1,2,3]');
1019select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '[1,2,3]');
1020
1021select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '{"1": 2}');
1022select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"1": 2}');
1023select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '{"1": 2}');
1024select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '{"1": 2}');
1025
1026select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '"test"');
1027select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"f": "test"}');
1028
1029select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{n}');
1030select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{b,-1}');
1031select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{d,1,0}');
1032
1033select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{n}';
1034select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1}';
1035select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1e}'; -- invalid array subscript
1036select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{d,1,0}';
1037
1038
1039-- empty structure and error conditions for delete and replace
1040
1041select '"a"'::jsonb - 'a'; -- error
1042select '{}'::jsonb - 'a';
1043select '[]'::jsonb - 'a';
1044select '"a"'::jsonb - 1; -- error
1045select '{}'::jsonb -  1; -- error
1046select '[]'::jsonb - 1;
1047select '"a"'::jsonb #- '{a}'; -- error
1048select '{}'::jsonb #- '{a}';
1049select '[]'::jsonb #- '{a}';
1050select jsonb_set('"a"','{a}','"b"'); --error
1051select jsonb_set('{}','{a}','"b"', false);
1052select jsonb_set('[]','{1}','"b"', false);
1053select jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0}','[2,3,4]', false);
1054
1055-- jsonb_set adding instead of replacing
1056
1057-- prepend to array
1058select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,-33}','{"foo":123}');
1059-- append to array
1060select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,33}','{"foo":123}');
1061-- check nesting levels addition
1062select jsonb_set('{"a":1,"b":[4,5,[0,1,2],6,7],"c":{"d":4}}','{b,2,33}','{"foo":123}');
1063-- add new key
1064select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{c,e}','{"foo":123}');
1065-- adding doesn't do anything if elements before last aren't present
1066select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,-33}','{"foo":123}');
1067select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,y}','{"foo":123}');
1068-- add to empty object
1069select jsonb_set('{}','{x}','{"foo":123}');
1070--add to empty array
1071select jsonb_set('[]','{0}','{"foo":123}');
1072select jsonb_set('[]','{99}','{"foo":123}');
1073select jsonb_set('[]','{-99}','{"foo":123}');
1074select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"');
1075select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"');
1076select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"');
1077
1078
1079-- jsonb_insert
1080select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');
1081select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true);
1082select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"');
1083select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"', true);
1084select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '{"b": "value"}');
1085select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '["value1", "value2"]');
1086
1087-- edge cases
1088select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"');
1089select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"', true);
1090select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"');
1091select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"', true);
1092select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"');
1093select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"', true);
1094select jsonb_insert('[]', '{1}', '"new_value"');
1095select jsonb_insert('[]', '{1}', '"new_value"', true);
1096select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"');
1097select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"', true);
1098select jsonb_insert('{"a": [0,1,2]}', '{a, 10}', '"new_value"');
1099select jsonb_insert('{"a": [0,1,2]}', '{a, -10}', '"new_value"');
1100
1101-- jsonb_insert should be able to insert new value for objects, but not to replace
1102select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"');
1103select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"', true);
1104
1105select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"');
1106select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"', true);
1107
1108-- jsonb to tsvector
1109select to_tsvector('{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
1110
1111-- jsonb to tsvector with config
1112select to_tsvector('simple', '{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
1113
1114-- jsonb to tsvector with stop words
1115select to_tsvector('english', '{"a": "aaa in bbb ddd ccc", "b": ["the eee fff ggg"], "c": {"d": "hhh. iii"}}'::jsonb);
1116
1117-- jsonb to tsvector with numeric values
1118select to_tsvector('english', '{"a": "aaa in bbb ddd ccc", "b": 123, "c": 456}'::jsonb);
1119
1120-- jsonb_to_tsvector
1121select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"all"');
1122select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"key"');
1123select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"string"');
1124select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"numeric"');
1125select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"boolean"');
1126select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["string", "numeric"]');
1127
1128select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"all"');
1129select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"key"');
1130select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"string"');
1131select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"numeric"');
1132select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"boolean"');
1133select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["string", "numeric"]');
1134
1135-- ts_vector corner cases
1136select to_tsvector('""'::jsonb);
1137select to_tsvector('{}'::jsonb);
1138select to_tsvector('[]'::jsonb);
1139select to_tsvector('null'::jsonb);
1140
1141-- jsonb_to_tsvector corner cases
1142select jsonb_to_tsvector('""'::jsonb, '"all"');
1143select jsonb_to_tsvector('{}'::jsonb, '"all"');
1144select jsonb_to_tsvector('[]'::jsonb, '"all"');
1145select jsonb_to_tsvector('null'::jsonb, '"all"');
1146
1147select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '""');
1148select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '{}');
1149select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '[]');
1150select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, 'null');
1151select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["all", null]');
1152
1153-- ts_headline for jsonb
1154select ts_headline('{"a": "aaa bbb", "b": {"c": "ccc ddd fff", "c1": "ccc1 ddd1"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'));
1155select ts_headline('english', '{"a": "aaa bbb", "b": {"c": "ccc ddd fff"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'));
1156select ts_headline('{"a": "aaa bbb", "b": {"c": "ccc ddd fff", "c1": "ccc1 ddd1"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'), 'StartSel = <, StopSel = >');
1157select ts_headline('english', '{"a": "aaa bbb", "b": {"c": "ccc ddd fff", "c1": "ccc1 ddd1"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'), 'StartSel = <, StopSel = >');
1158
1159-- corner cases for ts_headline with jsonb
1160select ts_headline('null'::jsonb, tsquery('aaa & bbb'));
1161select ts_headline('{}'::jsonb, tsquery('aaa & bbb'));
1162select ts_headline('[]'::jsonb, tsquery('aaa & bbb'));
1163
1164-- casts
1165select 'true'::jsonb::bool;
1166select '[]'::jsonb::bool;
1167select '1.0'::jsonb::float;
1168select '[1.0]'::jsonb::float;
1169select '12345'::jsonb::int4;
1170select '"hello"'::jsonb::int4;
1171select '12345'::jsonb::numeric;
1172select '{}'::jsonb::numeric;
1173select '12345.05'::jsonb::numeric;
1174select '12345.05'::jsonb::float4;
1175select '12345.05'::jsonb::float8;
1176select '12345.05'::jsonb::int2;
1177select '12345.05'::jsonb::int4;
1178select '12345.05'::jsonb::int8;
1179select '12345.0000000000000000000000000000000000000000000005'::jsonb::numeric;
1180select '12345.0000000000000000000000000000000000000000000005'::jsonb::float4;
1181select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
1182select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
1183select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
1184select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
1185