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-- to_jsonb, timestamps
66
67select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
68
69BEGIN;
70SET LOCAL TIME ZONE 10.5;
71select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
72SET LOCAL TIME ZONE -8;
73select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
74COMMIT;
75
76select to_jsonb(date '2014-05-28');
77
78select to_jsonb(date 'Infinity');
79select to_jsonb(date '-Infinity');
80select to_jsonb(timestamp 'Infinity');
81select to_jsonb(timestamp '-Infinity');
82select to_jsonb(timestamptz 'Infinity');
83select to_jsonb(timestamptz '-Infinity');
84
85--jsonb_agg
86
87CREATE TEMP TABLE rows AS
88SELECT x, 'txt' || x as y
89FROM generate_series(1,3) AS x;
90
91SELECT jsonb_agg(q)
92  FROM ( SELECT $$a$$ || x AS b, y AS c,
93               ARRAY[ROW(x.*,ARRAY[1,2,3]),
94               ROW(y.*,ARRAY[4,5,6])] AS z
95         FROM generate_series(1,2) x,
96              generate_series(4,5) y) q;
97
98SELECT jsonb_agg(q ORDER BY x, y)
99  FROM rows q;
100
101UPDATE rows SET x = NULL WHERE x = 1;
102
103SELECT jsonb_agg(q ORDER BY x NULLS FIRST, y)
104  FROM rows q;
105
106-- jsonb extraction functions
107CREATE TEMP TABLE test_jsonb (
108       json_type text,
109       test_json jsonb
110);
111
112INSERT INTO test_jsonb VALUES
113('scalar','"a scalar"'),
114('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
115('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
116
117SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'scalar';
118SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'array';
119SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'object';
120SELECT test_json -> 'field2' FROM test_jsonb WHERE json_type = 'object';
121
122SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'scalar';
123SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'array';
124SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'object';
125
126SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'scalar';
127SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'array';
128SELECT test_json -> 9 FROM test_jsonb WHERE json_type = 'array';
129SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'object';
130
131SELECT test_json ->> 6 FROM test_jsonb WHERE json_type = 'array';
132SELECT test_json ->> 7 FROM test_jsonb WHERE json_type = 'array';
133
134SELECT test_json ->> 'field4' FROM test_jsonb WHERE json_type = 'object';
135SELECT test_json ->> 'field5' FROM test_jsonb WHERE json_type = 'object';
136SELECT test_json ->> 'field6' FROM test_jsonb WHERE json_type = 'object';
137
138SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'scalar';
139SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'array';
140SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'object';
141
142SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'scalar';
143SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'array';
144SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'object';
145
146-- nulls
147SELECT (test_json->'field3') IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'object';
148SELECT (test_json->>'field3') IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'object';
149SELECT (test_json->3) IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'array';
150SELECT (test_json->>3) IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'array';
151
152-- corner cases
153select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::text;
154select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::int;
155select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 1;
156select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 'z';
157select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> '';
158select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 1;
159select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 3;
160select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 'z';
161select '{"a": "c", "b": null}'::jsonb -> 'b';
162select '"foo"'::jsonb -> 1;
163select '"foo"'::jsonb -> 'z';
164
165select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::text;
166select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::int;
167select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 1;
168select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 'z';
169select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> '';
170select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 1;
171select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 3;
172select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 'z';
173select '{"a": "c", "b": null}'::jsonb ->> 'b';
174select '"foo"'::jsonb ->> 1;
175select '"foo"'::jsonb ->> 'z';
176
177-- equality and inequality
178SELECT '{"x":"y"}'::jsonb = '{"x":"y"}'::jsonb;
179SELECT '{"x":"y"}'::jsonb = '{"x":"z"}'::jsonb;
180
181SELECT '{"x":"y"}'::jsonb <> '{"x":"y"}'::jsonb;
182SELECT '{"x":"y"}'::jsonb <> '{"x":"z"}'::jsonb;
183
184-- containment
185SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
186SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":null}');
187SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "g":null}');
188SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"g":null}');
189SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"c"}');
190SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
191SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":"q"}');
192SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
193SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":null}';
194SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "g":null}';
195SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"g":null}';
196SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"c"}';
197SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
198SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":"q"}';
199
200SELECT '[1,2]'::jsonb @> '[1,2,2]'::jsonb;
201SELECT '[1,1,2]'::jsonb @> '[1,2,2]'::jsonb;
202SELECT '[[1,2]]'::jsonb @> '[[1,2,2]]'::jsonb;
203SELECT '[1,2,2]'::jsonb <@ '[1,2]'::jsonb;
204SELECT '[1,2,2]'::jsonb <@ '[1,1,2]'::jsonb;
205SELECT '[[1,2,2]]'::jsonb <@ '[[1,2]]'::jsonb;
206
207SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
208SELECT jsonb_contained('{"a":"b", "c":null}', '{"a":"b", "b":1, "c":null}');
209SELECT jsonb_contained('{"a":"b", "g":null}', '{"a":"b", "b":1, "c":null}');
210SELECT jsonb_contained('{"g":null}', '{"a":"b", "b":1, "c":null}');
211SELECT jsonb_contained('{"a":"c"}', '{"a":"b", "b":1, "c":null}');
212SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
213SELECT jsonb_contained('{"a":"b", "c":"q"}', '{"a":"b", "b":1, "c":null}');
214SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
215SELECT '{"a":"b", "c":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
216SELECT '{"a":"b", "g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
217SELECT '{"g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
218SELECT '{"a":"c"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
219SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
220SELECT '{"a":"b", "c":"q"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
221-- Raw scalar may contain another raw scalar, array may contain a raw scalar
222SELECT '[5]'::jsonb @> '[5]';
223SELECT '5'::jsonb @> '5';
224SELECT '[5]'::jsonb @> '5';
225-- But a raw scalar cannot contain an array
226SELECT '5'::jsonb @> '[5]';
227-- In general, one thing should always contain itself. Test array containment:
228SELECT '["9", ["7", "3"], 1]'::jsonb @> '["9", ["7", "3"], 1]'::jsonb;
229SELECT '["9", ["7", "3"], ["1"]]'::jsonb @> '["9", ["7", "3"], ["1"]]'::jsonb;
230-- array containment string matching confusion bug
231SELECT '{ "name": "Bob", "tags": [ "enim", "qui"]}'::jsonb @> '{"tags":["qu"]}';
232
233-- array length
234SELECT jsonb_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
235SELECT jsonb_array_length('[]');
236SELECT jsonb_array_length('{"f1":1,"f2":[5,6]}');
237SELECT jsonb_array_length('4');
238
239-- each
240SELECT jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
241SELECT jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
242SELECT * FROM jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
243SELECT * FROM jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
244
245SELECT jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
246SELECT jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
247SELECT * FROM jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
248SELECT * FROM jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
249
250-- exists
251SELECT jsonb_exists('{"a":null, "b":"qq"}', 'a');
252SELECT jsonb_exists('{"a":null, "b":"qq"}', 'b');
253SELECT jsonb_exists('{"a":null, "b":"qq"}', 'c');
254SELECT jsonb_exists('{"a":"null", "b":"qq"}', 'a');
255SELECT jsonb '{"a":null, "b":"qq"}' ? 'a';
256SELECT jsonb '{"a":null, "b":"qq"}' ? 'b';
257SELECT jsonb '{"a":null, "b":"qq"}' ? 'c';
258SELECT jsonb '{"a":"null", "b":"qq"}' ? 'a';
259-- array exists - array elements should behave as keys
260SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
261-- type sensitive array exists - should return no rows (since "exists" only
262-- matches strings that are either object keys or array elements)
263SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
264-- However, a raw scalar is *contained* within the array
265SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
266
267SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['a','b']);
268SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['b','a']);
269SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','a']);
270SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','d']);
271SELECT jsonb_exists_any('{"a":null, "b":"qq"}', '{}'::text[]);
272SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['a','b'];
273SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['b','a'];
274SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','a'];
275SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','d'];
276SELECT jsonb '{"a":null, "b":"qq"}' ?| '{}'::text[];
277
278SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['a','b']);
279SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['b','a']);
280SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','a']);
281SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','d']);
282SELECT jsonb_exists_all('{"a":null, "b":"qq"}', '{}'::text[]);
283SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','b'];
284SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['b','a'];
285SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','a'];
286SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','d'];
287SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','a', 'b', 'b', 'b'];
288SELECT jsonb '{"a":null, "b":"qq"}' ?& '{}'::text[];
289
290-- typeof
291SELECT jsonb_typeof('{}') AS object;
292SELECT jsonb_typeof('{"c":3,"p":"o"}') AS object;
293SELECT jsonb_typeof('[]') AS array;
294SELECT jsonb_typeof('["a", 1]') AS array;
295SELECT jsonb_typeof('null') AS "null";
296SELECT jsonb_typeof('1') AS number;
297SELECT jsonb_typeof('-1') AS number;
298SELECT jsonb_typeof('1.0') AS number;
299SELECT jsonb_typeof('1e2') AS number;
300SELECT jsonb_typeof('-1.0') AS number;
301SELECT jsonb_typeof('true') AS boolean;
302SELECT jsonb_typeof('false') AS boolean;
303SELECT jsonb_typeof('"hello"') AS string;
304SELECT jsonb_typeof('"true"') AS string;
305SELECT jsonb_typeof('"1.0"') AS string;
306
307-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
308
309SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
310SELECT jsonb_build_array('a', NULL); -- ok
311SELECT jsonb_build_array(VARIADIC NULL::text[]); -- ok
312SELECT jsonb_build_array(VARIADIC '{}'::text[]); -- ok
313SELECT jsonb_build_array(VARIADIC '{a,b,c}'::text[]); -- ok
314SELECT jsonb_build_array(VARIADIC ARRAY['a', NULL]::text[]); -- ok
315SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::text[]); -- ok
316SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::int[]); -- ok
317SELECT jsonb_build_array(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
318
319SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
320
321SELECT jsonb_build_object(
322       'a', jsonb_build_object('b',false,'c',99),
323       'd', jsonb_build_object('e',array[9,8,7]::int[],
324           'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
325SELECT jsonb_build_object('{a,b,c}'::text[]); -- error
326SELECT jsonb_build_object('{a,b,c}'::text[], '{d,e,f}'::text[]); -- error, key cannot be array
327SELECT jsonb_build_object('a', 'b', 'c'); -- error
328SELECT jsonb_build_object(NULL, 'a'); -- error, key cannot be NULL
329SELECT jsonb_build_object('a', NULL); -- ok
330SELECT jsonb_build_object(VARIADIC NULL::text[]); -- ok
331SELECT jsonb_build_object(VARIADIC '{}'::text[]); -- ok
332SELECT jsonb_build_object(VARIADIC '{a,b,c}'::text[]); -- error
333SELECT jsonb_build_object(VARIADIC ARRAY['a', NULL]::text[]); -- ok
334SELECT jsonb_build_object(VARIADIC ARRAY[NULL, 'a']::text[]); -- error, key cannot be NULL
335SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::text[]); -- ok
336SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::int[]); -- ok
337SELECT jsonb_build_object(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
338
339-- empty objects/arrays
340SELECT jsonb_build_array();
341
342SELECT jsonb_build_object();
343
344-- make sure keys are quoted
345SELECT jsonb_build_object(1,2);
346
347-- keys must be scalar and not null
348SELECT jsonb_build_object(null,2);
349
350SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
351
352SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
353
354SELECT jsonb_build_object('{1,2,3}'::int[], 3);
355
356-- handling of NULL values
357SELECT jsonb_object_agg(1, NULL::jsonb);
358SELECT jsonb_object_agg(NULL, '{"a":1}');
359
360CREATE TEMP TABLE foo (serial_num int, name text, type text);
361INSERT INTO foo VALUES (847001,'t15','GE1043');
362INSERT INTO foo VALUES (847002,'t16','GE1043');
363INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
364
365SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
366FROM foo;
367
368SELECT jsonb_object_agg(name, type) FROM foo;
369
370INSERT INTO foo VALUES (999999, NULL, 'bar');
371SELECT jsonb_object_agg(name, type) FROM foo;
372
373-- jsonb_object
374
375-- empty object, one dimension
376SELECT jsonb_object('{}');
377
378-- empty object, two dimensions
379SELECT jsonb_object('{}', '{}');
380
381-- one dimension
382SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
383
384-- same but with two dimensions
385SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
386
387-- odd number error
388SELECT jsonb_object('{a,b,c}');
389
390-- one column error
391SELECT jsonb_object('{{a},{b}}');
392
393-- too many columns error
394SELECT jsonb_object('{{a,b,c},{b,c,d}}');
395
396-- too many dimensions error
397SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
398
399--two argument form of jsonb_object
400
401select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
402
403-- too many dimensions
404SELECT 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"}}');
405
406-- mismatched dimensions
407
408select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
409
410select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
411
412-- null key error
413
414select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
415
416-- empty key is allowed
417
418select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
419
420
421
422-- extract_path, extract_path_as_text
423SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
424SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
425SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
426SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
427SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
428SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
429SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
430SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
431
432-- extract_path nulls
433SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_false;
434SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_true;
435SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_false;
436SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_true;
437
438-- extract_path operators
439SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f4','f6'];
440SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2'];
441SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','0'];
442SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','1'];
443
444SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f4','f6'];
445SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2'];
446SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','0'];
447SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','1'];
448
449-- corner cases for same
450select '{"a": {"b":{"c": "foo"}}}'::jsonb #> '{}';
451select '[1,2,3]'::jsonb #> '{}';
452select '"foo"'::jsonb #> '{}';
453select '42'::jsonb #> '{}';
454select 'null'::jsonb #> '{}';
455select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a'];
456select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a', null];
457select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a', ''];
458select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b'];
459select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b','c'];
460select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','b','c','d'];
461select '{"a": {"b":{"c": "foo"}}}'::jsonb #> array['a','z','c'];
462select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #> array['a','1','b'];
463select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #> array['a','z','b'];
464select '[{"b": "c"}, {"b": "cc"}]'::jsonb #> array['1','b'];
465select '[{"b": "c"}, {"b": "cc"}]'::jsonb #> array['z','b'];
466select '[{"b": "c"}, {"b": null}]'::jsonb #> array['1','b'];
467select '"foo"'::jsonb #> array['z'];
468select '42'::jsonb #> array['f2'];
469select '42'::jsonb #> array['0'];
470
471select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> '{}';
472select '[1,2,3]'::jsonb #>> '{}';
473select '"foo"'::jsonb #>> '{}';
474select '42'::jsonb #>> '{}';
475select 'null'::jsonb #>> '{}';
476select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a'];
477select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', null];
478select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', ''];
479select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b'];
480select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c'];
481select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c','d'];
482select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','z','c'];
483select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','1','b'];
484select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','z','b'];
485select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['1','b'];
486select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['z','b'];
487select '[{"b": "c"}, {"b": null}]'::jsonb #>> array['1','b'];
488select '"foo"'::jsonb #>> array['z'];
489select '42'::jsonb #>> array['f2'];
490select '42'::jsonb #>> array['0'];
491
492-- array_elements
493SELECT jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
494SELECT * FROM jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
495SELECT jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
496SELECT * FROM jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
497
498-- populate_record
499CREATE TYPE jbpop AS (a text, b int, c timestamp);
500
501SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
502SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
503
504SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
505SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
506
507SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":[100,200,false],"x":43.2}') q;
508SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":[100,200,false],"x":43.2}') q;
509SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"c":[100,200,false],"x":43.2}') q;
510
511-- populate_recordset
512SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
513SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
514SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
515SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
516SELECT * 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;
517SELECT * 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;
518
519SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
520SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
521SELECT * 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;
522
523-- negative cases where the wrong record type is supplied
524select * from jsonb_populate_recordset(row(0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
525select * from jsonb_populate_recordset(row(0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
526select * from jsonb_populate_recordset(row(0::int,0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
527select * from jsonb_populate_recordset(row(1000000000::int,50::int),'[{"b":"2"},{"a":"3"}]') q (a text, b text);
528
529-- jsonb_to_record and jsonb_to_recordset
530
531select * from jsonb_to_record('{"a":1,"b":"foo","c":"bar"}')
532    as x(a int, b text, d text);
533
534select * from jsonb_to_recordset('[{"a":1,"b":"foo","d":false},{"a":2,"b":"bar","c":true}]')
535    as x(a int, b text, c boolean);
536
537select *, c is null as c_is_null
538from jsonb_to_record('{"a":1, "b":{"c":16, "d":2}, "x":8}'::jsonb)
539    as t(a int, b jsonb, c text, x int);
540
541select *, c is null as c_is_null
542from jsonb_to_recordset('[{"a":1, "b":{"c":16, "d":2}, "x":8}]'::jsonb)
543    as t(a int, b jsonb, c text, x int);
544
545-- indexing
546SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
547SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
548SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
549SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
550SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
551SELECT count(*) FROM testjsonb WHERE j ? 'public';
552SELECT count(*) FROM testjsonb WHERE j ? 'bar';
553SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
554SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
555
556CREATE INDEX jidx ON testjsonb USING gin (j);
557SET enable_seqscan = off;
558
559SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
560SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
561SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
562SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
563SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
564SELECT count(*) FROM testjsonb WHERE j @> '{"array":["foo"]}';
565SELECT count(*) FROM testjsonb WHERE j @> '{"array":["bar"]}';
566-- exercise GIN_SEARCH_MODE_ALL
567SELECT count(*) FROM testjsonb WHERE j @> '{}';
568SELECT count(*) FROM testjsonb WHERE j ? 'public';
569SELECT count(*) FROM testjsonb WHERE j ? 'bar';
570SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
571SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
572
573-- array exists - array elements should behave as keys (for GIN index scans too)
574CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
575SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
576-- type sensitive array exists - should return no rows (since "exists" only
577-- matches strings that are either object keys or array elements)
578SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
579-- However, a raw scalar is *contained* within the array
580SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
581
582RESET enable_seqscan;
583
584SELECT count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow;
585SELECT key, count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow GROUP BY key ORDER BY count DESC, key;
586
587-- sort/hash
588SELECT count(distinct j) FROM testjsonb;
589SET enable_hashagg = off;
590SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
591SET enable_hashagg = on;
592SET enable_sort = off;
593SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
594SELECT distinct * FROM (values (jsonb '{}' || ''::text),('{}')) v(j);
595SET enable_sort = on;
596
597RESET enable_hashagg;
598RESET enable_sort;
599
600DROP INDEX jidx;
601DROP INDEX jidx_array;
602-- btree
603CREATE INDEX jidx ON testjsonb USING btree (j);
604SET enable_seqscan = off;
605
606SELECT count(*) FROM testjsonb WHERE j > '{"p":1}';
607SELECT count(*) FROM testjsonb WHERE j = '{"pos":98, "line":371, "node":"CBA", "indexed":true}';
608
609--gin path opclass
610DROP INDEX jidx;
611CREATE INDEX jidx ON testjsonb USING gin (j jsonb_path_ops);
612SET enable_seqscan = off;
613
614SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
615SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
616SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
617SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
618SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
619-- exercise GIN_SEARCH_MODE_ALL
620SELECT count(*) FROM testjsonb WHERE j @> '{}';
621
622RESET enable_seqscan;
623DROP INDEX jidx;
624
625-- nested tests
626SELECT '{"ff":{"a":12,"b":16}}'::jsonb;
627SELECT '{"ff":{"a":12,"b":16},"qq":123}'::jsonb;
628SELECT '{"aa":["a","aaa"],"qq":{"a":12,"b":16,"c":["c1","c2"],"d":{"d1":"d1","d2":"d2","d1":"d3"}}}'::jsonb;
629SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2"],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
630SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2",["c3"],{"c4":4}],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
631SELECT '{"ff":["a","aaa"]}'::jsonb;
632
633SELECT
634  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'ff',
635  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'qq',
636  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'Y') IS NULL AS f,
637  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb ->> 'Y') IS NULL AS t,
638   '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'x';
639
640-- nested containment
641SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1,2]}';
642SELECT '{"a":[2,1],"c":"b"}'::jsonb @> '{"a":[1,2]}';
643SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":[1,2]}';
644SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":[1,2]}';
645SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
646SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
647SELECT '["a","b"]'::jsonb @> '["a","b","c","b"]';
648SELECT '["a","b","c","b"]'::jsonb @> '["a","b"]';
649SELECT '["a","b","c",[1,2]]'::jsonb @> '["a",[1,2]]';
650SELECT '["a","b","c",[1,2]]'::jsonb @> '["b",[1,2]]';
651
652SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1]}';
653SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[2]}';
654SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[3]}';
655
656SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"c":3}]}';
657SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4}]}';
658SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},3]}';
659SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},1]}';
660
661-- check some corner cases for indexed nested containment (bug #13756)
662create temp table nestjsonb (j jsonb);
663insert into nestjsonb (j) values ('{"a":[["b",{"x":1}],["b",{"x":2}]],"c":3}');
664insert into nestjsonb (j) values ('[[14,2,3]]');
665insert into nestjsonb (j) values ('[1,[14,2,3]]');
666create index on nestjsonb using gin(j jsonb_path_ops);
667
668set enable_seqscan = on;
669set enable_bitmapscan = off;
670select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
671select * from nestjsonb where j @> '{"c":3}';
672select * from nestjsonb where j @> '[[14]]';
673set enable_seqscan = off;
674set enable_bitmapscan = on;
675select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
676select * from nestjsonb where j @> '{"c":3}';
677select * from nestjsonb where j @> '[[14]]';
678reset enable_seqscan;
679reset enable_bitmapscan;
680
681-- nested object field / array index lookup
682SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'n';
683SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'a';
684SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'b';
685SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'c';
686SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd';
687SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd' -> '1';
688SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'e';
689SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 0; --expecting error
690
691SELECT '["a","b","c",[1,2],null]'::jsonb -> 0;
692SELECT '["a","b","c",[1,2],null]'::jsonb -> 1;
693SELECT '["a","b","c",[1,2],null]'::jsonb -> 2;
694SELECT '["a","b","c",[1,2],null]'::jsonb -> 3;
695SELECT '["a","b","c",[1,2],null]'::jsonb -> 3 -> 1;
696SELECT '["a","b","c",[1,2],null]'::jsonb -> 4;
697SELECT '["a","b","c",[1,2],null]'::jsonb -> 5;
698SELECT '["a","b","c",[1,2],null]'::jsonb -> -1;
699SELECT '["a","b","c",[1,2],null]'::jsonb -> -5;
700SELECT '["a","b","c",[1,2],null]'::jsonb -> -6;
701
702--nested path extraction
703SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{0}';
704SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{a}';
705SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c}';
706SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,0}';
707SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,1}';
708SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,2}';
709SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,3}';
710SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-1}';
711SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-3}';
712SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-4}';
713
714SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{0}';
715SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{3}';
716SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4}';
717SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4,5}';
718
719--nested exists
720SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'n';
721SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'a';
722SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'b';
723SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'c';
724SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'd';
725SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'e';
726
727-- jsonb_strip_nulls
728
729select jsonb_strip_nulls(null);
730
731select jsonb_strip_nulls('1');
732
733select jsonb_strip_nulls('"a string"');
734
735select jsonb_strip_nulls('null');
736
737select jsonb_strip_nulls('[1,2,null,3,4]');
738
739select jsonb_strip_nulls('{"a":1,"b":null,"c":[2,null,3],"d":{"e":4,"f":null}}');
740
741select jsonb_strip_nulls('[1,{"a":1,"b":null,"c":2},3]');
742
743-- an empty object is not null and should not be stripped
744select jsonb_strip_nulls('{"a": {"b": null, "c": null}, "d": {} }');
745
746
747select jsonb_pretty('{"a": "test", "b": [1, 2, 3], "c": "test3", "d":{"dd": "test4", "dd2":{"ddd": "test5"}}}');
748select jsonb_pretty('[{"f1":1,"f2":null},2,null,[[{"x":true},6,7],8],3]');
749select jsonb_pretty('{"a":["b", "c"], "d": {"e":"f"}}');
750
751select jsonb_concat('{"d": "test", "a": [1, 2]}', '{"g": "test2", "c": {"c1":1, "c2":2}}');
752
753select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
754select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aq":"l"}';
755select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aa":"l"}';
756select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{}';
757
758select '["a", "b"]'::jsonb || '["c"]';
759select '["a", "b"]'::jsonb || '["c", "d"]';
760select '["c"]' || '["a", "b"]'::jsonb;
761
762select '["a", "b"]'::jsonb || '"c"';
763select '"c"' || '["a", "b"]'::jsonb;
764
765select '[]'::jsonb || '["a"]'::jsonb;
766select '[]'::jsonb || '"a"'::jsonb;
767select '"b"'::jsonb || '"a"'::jsonb;
768select '{}'::jsonb || '{"a":"b"}'::jsonb;
769select '[]'::jsonb || '{"a":"b"}'::jsonb;
770select '{"a":"b"}'::jsonb || '[]'::jsonb;
771
772select '"a"'::jsonb || '{"a":1}';
773select '{"a":1}' || '"a"'::jsonb;
774
775select '[3]'::jsonb || '{}'::jsonb;
776select '3'::jsonb || '[]'::jsonb;
777select '3'::jsonb || '4'::jsonb;
778select '3'::jsonb || '{}'::jsonb;
779
780select '["a", "b"]'::jsonb || '{"c":1}';
781select '{"c": 1}'::jsonb || '["a", "b"]';
782
783select '{}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
784
785select pg_column_size('{}'::jsonb || '{}'::jsonb) = pg_column_size('{}'::jsonb);
786select pg_column_size('{"aa":1}'::jsonb || '{"b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
787select pg_column_size('{"aa":1, "b":2}'::jsonb || '{}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
788select pg_column_size('{}'::jsonb || '{"aa":1, "b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
789
790select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'a');
791select jsonb_delete('{"a":null , "b":2, "c":3}'::jsonb, 'a');
792select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'b');
793select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'c');
794select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'd');
795select '{"a":1 , "b":2, "c":3}'::jsonb - 'a';
796select '{"a":null , "b":2, "c":3}'::jsonb - 'a';
797select '{"a":1 , "b":2, "c":3}'::jsonb - 'b';
798select '{"a":1 , "b":2, "c":3}'::jsonb - 'c';
799select '{"a":1 , "b":2, "c":3}'::jsonb - 'd';
800select pg_column_size('{"a":1 , "b":2, "c":3}'::jsonb - 'b') = pg_column_size('{"a":1, "b":2}'::jsonb);
801
802select '["a","b","c"]'::jsonb - 3;
803select '["a","b","c"]'::jsonb - 2;
804select '["a","b","c"]'::jsonb - 1;
805select '["a","b","c"]'::jsonb - 0;
806select '["a","b","c"]'::jsonb - -1;
807select '["a","b","c"]'::jsonb - -2;
808select '["a","b","c"]'::jsonb - -3;
809select '["a","b","c"]'::jsonb - -4;
810
811select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '[1,2,3]');
812select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '[1,2,3]');
813select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '[1,2,3]');
814select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '[1,2,3]');
815
816select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '{"1": 2}');
817select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"1": 2}');
818select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '{"1": 2}');
819select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '{"1": 2}');
820
821select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '"test"');
822select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"f": "test"}');
823
824select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{n}');
825select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{b,-1}');
826select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{d,1,0}');
827
828select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{n}';
829select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1}';
830select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1e}'; -- invalid array subscript
831select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{d,1,0}';
832
833
834-- empty structure and error conditions for delete and replace
835
836select '"a"'::jsonb - 'a'; -- error
837select '{}'::jsonb - 'a';
838select '[]'::jsonb - 'a';
839select '"a"'::jsonb - 1; -- error
840select '{}'::jsonb -  1; -- error
841select '[]'::jsonb - 1;
842select '"a"'::jsonb #- '{a}'; -- error
843select '{}'::jsonb #- '{a}';
844select '[]'::jsonb #- '{a}';
845select jsonb_set('"a"','{a}','"b"'); --error
846select jsonb_set('{}','{a}','"b"', false);
847select jsonb_set('[]','{1}','"b"', false);
848select jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0}','[2,3,4]', false);
849
850-- jsonb_set adding instead of replacing
851
852-- prepend to array
853select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,-33}','{"foo":123}');
854-- append to array
855select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,33}','{"foo":123}');
856-- check nesting levels addition
857select jsonb_set('{"a":1,"b":[4,5,[0,1,2],6,7],"c":{"d":4}}','{b,2,33}','{"foo":123}');
858-- add new key
859select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{c,e}','{"foo":123}');
860-- adding doesn't do anything if elements before last aren't present
861select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,-33}','{"foo":123}');
862select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,y}','{"foo":123}');
863-- add to empty object
864select jsonb_set('{}','{x}','{"foo":123}');
865--add to empty array
866select jsonb_set('[]','{0}','{"foo":123}');
867select jsonb_set('[]','{99}','{"foo":123}');
868select jsonb_set('[]','{-99}','{"foo":123}');
869select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"');
870select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"');
871select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"');
872
873
874-- jsonb_insert
875select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');
876select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true);
877select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"');
878select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"', true);
879select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '{"b": "value"}');
880select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '["value1", "value2"]');
881
882-- edge cases
883select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"');
884select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"', true);
885select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"');
886select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"', true);
887select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"');
888select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"', true);
889select jsonb_insert('[]', '{1}', '"new_value"');
890select jsonb_insert('[]', '{1}', '"new_value"', true);
891select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"');
892select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"', true);
893select jsonb_insert('{"a": [0,1,2]}', '{a, 10}', '"new_value"');
894select jsonb_insert('{"a": [0,1,2]}', '{a, -10}', '"new_value"');
895
896-- jsonb_insert should be able to insert new value for objects, but not to replace
897select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"');
898select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"', true);
899
900select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"');
901select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"', true);
902