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-- Multi-line JSON input to check ERROR reporting
63SELECT '{
64		"one": 1,
65		"two":"two",
66		"three":
67		true}'::jsonb; -- OK
68SELECT '{
69		"one": 1,
70		"two":,"two",  -- ERROR extraneous comma before field "two"
71		"three":
72		true}'::jsonb;
73SELECT '{
74		"one": 1,
75		"two":"two",
76		"averyveryveryveryveryveryveryveryveryverylongfieldname":}'::jsonb;
77-- ERROR missing value for last field
78
79-- make sure jsonb is passed through json generators without being escaped
80SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
81
82-- anyarray column
83
84CREATE TEMP TABLE rows AS
85SELECT x, 'txt' || x as y
86FROM generate_series(1,3) AS x;
87
88analyze rows;
89
90select attname, to_jsonb(histogram_bounds) histogram_bounds
91from pg_stats
92where tablename = 'rows' and
93      schemaname = pg_my_temp_schema()::regnamespace::text
94order by 1;
95
96-- to_jsonb, timestamps
97
98select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
99
100BEGIN;
101SET LOCAL TIME ZONE 10.5;
102select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
103SET LOCAL TIME ZONE -8;
104select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
105COMMIT;
106
107select to_jsonb(date '2014-05-28');
108
109select to_jsonb(date 'Infinity');
110select to_jsonb(date '-Infinity');
111select to_jsonb(timestamp 'Infinity');
112select to_jsonb(timestamp '-Infinity');
113select to_jsonb(timestamptz 'Infinity');
114select to_jsonb(timestamptz '-Infinity');
115
116--jsonb_agg
117
118SELECT jsonb_agg(q)
119  FROM ( SELECT $$a$$ || x AS b, y AS c,
120               ARRAY[ROW(x.*,ARRAY[1,2,3]),
121               ROW(y.*,ARRAY[4,5,6])] AS z
122         FROM generate_series(1,2) x,
123              generate_series(4,5) y) q;
124
125SELECT jsonb_agg(q ORDER BY x, y)
126  FROM rows q;
127
128UPDATE rows SET x = NULL WHERE x = 1;
129
130SELECT jsonb_agg(q ORDER BY x NULLS FIRST, y)
131  FROM rows q;
132
133-- jsonb extraction functions
134CREATE TEMP TABLE test_jsonb (
135       json_type text,
136       test_json jsonb
137);
138
139INSERT INTO test_jsonb VALUES
140('scalar','"a scalar"'),
141('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
142('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
143
144SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'scalar';
145SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'array';
146SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'object';
147SELECT test_json -> 'field2' FROM test_jsonb WHERE json_type = 'object';
148
149SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'scalar';
150SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'array';
151SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'object';
152
153SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'scalar';
154SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'array';
155SELECT test_json -> 9 FROM test_jsonb WHERE json_type = 'array';
156SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'object';
157
158SELECT test_json ->> 6 FROM test_jsonb WHERE json_type = 'array';
159SELECT test_json ->> 7 FROM test_jsonb WHERE json_type = 'array';
160
161SELECT test_json ->> 'field4' FROM test_jsonb WHERE json_type = 'object';
162SELECT test_json ->> 'field5' FROM test_jsonb WHERE json_type = 'object';
163SELECT test_json ->> 'field6' FROM test_jsonb WHERE json_type = 'object';
164
165SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'scalar';
166SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'array';
167SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'object';
168
169SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'scalar';
170SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'array';
171SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'object';
172
173-- nulls
174SELECT (test_json->'field3') IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'object';
175SELECT (test_json->>'field3') IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'object';
176SELECT (test_json->3) IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'array';
177SELECT (test_json->>3) IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'array';
178
179-- corner cases
180select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::text;
181select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> null::int;
182select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 1;
183select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> 'z';
184select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb -> '';
185select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 1;
186select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 3;
187select '[{"b": "c"}, {"b": "cc"}]'::jsonb -> 'z';
188select '{"a": "c", "b": null}'::jsonb -> 'b';
189select '"foo"'::jsonb -> 1;
190select '"foo"'::jsonb -> 'z';
191
192select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::text;
193select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> null::int;
194select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 1;
195select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> 'z';
196select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb ->> '';
197select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 1;
198select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 3;
199select '[{"b": "c"}, {"b": "cc"}]'::jsonb ->> 'z';
200select '{"a": "c", "b": null}'::jsonb ->> 'b';
201select '"foo"'::jsonb ->> 1;
202select '"foo"'::jsonb ->> 'z';
203
204-- equality and inequality
205SELECT '{"x":"y"}'::jsonb = '{"x":"y"}'::jsonb;
206SELECT '{"x":"y"}'::jsonb = '{"x":"z"}'::jsonb;
207
208SELECT '{"x":"y"}'::jsonb <> '{"x":"y"}'::jsonb;
209SELECT '{"x":"y"}'::jsonb <> '{"x":"z"}'::jsonb;
210
211-- containment
212SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
213SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":null}');
214SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "g":null}');
215SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"g":null}');
216SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"c"}');
217SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
218SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":"q"}');
219SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
220SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":null}';
221SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "g":null}';
222SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"g":null}';
223SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"c"}';
224SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
225SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":"q"}';
226
227SELECT '[1,2]'::jsonb @> '[1,2,2]'::jsonb;
228SELECT '[1,1,2]'::jsonb @> '[1,2,2]'::jsonb;
229SELECT '[[1,2]]'::jsonb @> '[[1,2,2]]'::jsonb;
230SELECT '[1,2,2]'::jsonb <@ '[1,2]'::jsonb;
231SELECT '[1,2,2]'::jsonb <@ '[1,1,2]'::jsonb;
232SELECT '[[1,2,2]]'::jsonb <@ '[[1,2]]'::jsonb;
233
234SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
235SELECT jsonb_contained('{"a":"b", "c":null}', '{"a":"b", "b":1, "c":null}');
236SELECT jsonb_contained('{"a":"b", "g":null}', '{"a":"b", "b":1, "c":null}');
237SELECT jsonb_contained('{"g":null}', '{"a":"b", "b":1, "c":null}');
238SELECT jsonb_contained('{"a":"c"}', '{"a":"b", "b":1, "c":null}');
239SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
240SELECT jsonb_contained('{"a":"b", "c":"q"}', '{"a":"b", "b":1, "c":null}');
241SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
242SELECT '{"a":"b", "c":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
243SELECT '{"a":"b", "g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
244SELECT '{"g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
245SELECT '{"a":"c"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
246SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
247SELECT '{"a":"b", "c":"q"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
248-- Raw scalar may contain another raw scalar, array may contain a raw scalar
249SELECT '[5]'::jsonb @> '[5]';
250SELECT '5'::jsonb @> '5';
251SELECT '[5]'::jsonb @> '5';
252-- But a raw scalar cannot contain an array
253SELECT '5'::jsonb @> '[5]';
254-- In general, one thing should always contain itself. Test array containment:
255SELECT '["9", ["7", "3"], 1]'::jsonb @> '["9", ["7", "3"], 1]'::jsonb;
256SELECT '["9", ["7", "3"], ["1"]]'::jsonb @> '["9", ["7", "3"], ["1"]]'::jsonb;
257-- array containment string matching confusion bug
258SELECT '{ "name": "Bob", "tags": [ "enim", "qui"]}'::jsonb @> '{"tags":["qu"]}';
259
260-- array length
261SELECT jsonb_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
262SELECT jsonb_array_length('[]');
263SELECT jsonb_array_length('{"f1":1,"f2":[5,6]}');
264SELECT jsonb_array_length('4');
265
266-- each
267SELECT jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
268SELECT jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
269SELECT * FROM jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
270SELECT * FROM jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
271
272SELECT jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
273SELECT jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
274SELECT * FROM jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
275SELECT * FROM jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
276
277-- exists
278SELECT jsonb_exists('{"a":null, "b":"qq"}', 'a');
279SELECT jsonb_exists('{"a":null, "b":"qq"}', 'b');
280SELECT jsonb_exists('{"a":null, "b":"qq"}', 'c');
281SELECT jsonb_exists('{"a":"null", "b":"qq"}', 'a');
282SELECT jsonb '{"a":null, "b":"qq"}' ? 'a';
283SELECT jsonb '{"a":null, "b":"qq"}' ? 'b';
284SELECT jsonb '{"a":null, "b":"qq"}' ? 'c';
285SELECT jsonb '{"a":"null", "b":"qq"}' ? 'a';
286-- array exists - array elements should behave as keys
287SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
288-- type sensitive array exists - should return no rows (since "exists" only
289-- matches strings that are either object keys or array elements)
290SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
291-- However, a raw scalar is *contained* within the array
292SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
293
294SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['a','b']);
295SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['b','a']);
296SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','a']);
297SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','d']);
298SELECT jsonb_exists_any('{"a":null, "b":"qq"}', '{}'::text[]);
299SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['a','b'];
300SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['b','a'];
301SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','a'];
302SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','d'];
303SELECT jsonb '{"a":null, "b":"qq"}' ?| '{}'::text[];
304
305SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['a','b']);
306SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['b','a']);
307SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','a']);
308SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','d']);
309SELECT jsonb_exists_all('{"a":null, "b":"qq"}', '{}'::text[]);
310SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','b'];
311SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['b','a'];
312SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','a'];
313SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','d'];
314SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','a', 'b', 'b', 'b'];
315SELECT jsonb '{"a":null, "b":"qq"}' ?& '{}'::text[];
316
317-- typeof
318SELECT jsonb_typeof('{}') AS object;
319SELECT jsonb_typeof('{"c":3,"p":"o"}') AS object;
320SELECT jsonb_typeof('[]') AS array;
321SELECT jsonb_typeof('["a", 1]') AS array;
322SELECT jsonb_typeof('null') AS "null";
323SELECT jsonb_typeof('1') AS number;
324SELECT jsonb_typeof('-1') AS number;
325SELECT jsonb_typeof('1.0') AS number;
326SELECT jsonb_typeof('1e2') AS number;
327SELECT jsonb_typeof('-1.0') AS number;
328SELECT jsonb_typeof('true') AS boolean;
329SELECT jsonb_typeof('false') AS boolean;
330SELECT jsonb_typeof('"hello"') AS string;
331SELECT jsonb_typeof('"true"') AS string;
332SELECT jsonb_typeof('"1.0"') AS string;
333
334-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
335
336SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
337SELECT jsonb_build_array('a', NULL); -- ok
338SELECT jsonb_build_array(VARIADIC NULL::text[]); -- ok
339SELECT jsonb_build_array(VARIADIC '{}'::text[]); -- ok
340SELECT jsonb_build_array(VARIADIC '{a,b,c}'::text[]); -- ok
341SELECT jsonb_build_array(VARIADIC ARRAY['a', NULL]::text[]); -- ok
342SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::text[]); -- ok
343SELECT jsonb_build_array(VARIADIC '{1,2,3,4}'::int[]); -- ok
344SELECT jsonb_build_array(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
345
346SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
347
348SELECT jsonb_build_object(
349       'a', jsonb_build_object('b',false,'c',99),
350       'd', jsonb_build_object('e',array[9,8,7]::int[],
351           'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
352SELECT jsonb_build_object('{a,b,c}'::text[]); -- error
353SELECT jsonb_build_object('{a,b,c}'::text[], '{d,e,f}'::text[]); -- error, key cannot be array
354SELECT jsonb_build_object('a', 'b', 'c'); -- error
355SELECT jsonb_build_object(NULL, 'a'); -- error, key cannot be NULL
356SELECT jsonb_build_object('a', NULL); -- ok
357SELECT jsonb_build_object(VARIADIC NULL::text[]); -- ok
358SELECT jsonb_build_object(VARIADIC '{}'::text[]); -- ok
359SELECT jsonb_build_object(VARIADIC '{a,b,c}'::text[]); -- error
360SELECT jsonb_build_object(VARIADIC ARRAY['a', NULL]::text[]); -- ok
361SELECT jsonb_build_object(VARIADIC ARRAY[NULL, 'a']::text[]); -- error, key cannot be NULL
362SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::text[]); -- ok
363SELECT jsonb_build_object(VARIADIC '{1,2,3,4}'::int[]); -- ok
364SELECT jsonb_build_object(VARIADIC '{{1,4},{2,5},{3,6}}'::int[][]); -- ok
365
366-- empty objects/arrays
367SELECT jsonb_build_array();
368
369SELECT jsonb_build_object();
370
371-- make sure keys are quoted
372SELECT jsonb_build_object(1,2);
373
374-- keys must be scalar and not null
375SELECT jsonb_build_object(null,2);
376
377SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
378
379SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
380
381SELECT jsonb_build_object('{1,2,3}'::int[], 3);
382
383-- handling of NULL values
384SELECT jsonb_object_agg(1, NULL::jsonb);
385SELECT jsonb_object_agg(NULL, '{"a":1}');
386
387CREATE TEMP TABLE foo (serial_num int, name text, type text);
388INSERT INTO foo VALUES (847001,'t15','GE1043');
389INSERT INTO foo VALUES (847002,'t16','GE1043');
390INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
391
392SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
393FROM foo;
394
395SELECT jsonb_object_agg(name, type) FROM foo;
396
397INSERT INTO foo VALUES (999999, NULL, 'bar');
398SELECT jsonb_object_agg(name, type) FROM foo;
399
400-- jsonb_object
401
402-- empty object, one dimension
403SELECT jsonb_object('{}');
404
405-- empty object, two dimensions
406SELECT jsonb_object('{}', '{}');
407
408-- one dimension
409SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
410
411-- same but with two dimensions
412SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
413
414-- odd number error
415SELECT jsonb_object('{a,b,c}');
416
417-- one column error
418SELECT jsonb_object('{{a},{b}}');
419
420-- too many columns error
421SELECT jsonb_object('{{a,b,c},{b,c,d}}');
422
423-- too many dimensions error
424SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
425
426--two argument form of jsonb_object
427
428select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
429
430-- too many dimensions
431SELECT 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"}}');
432
433-- mismatched dimensions
434
435select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
436
437select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
438
439-- null key error
440
441select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
442
443-- empty key is allowed
444
445select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
446
447
448
449-- extract_path, extract_path_as_text
450SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
451SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
452SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
453SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
454SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
455SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
456SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
457SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
458
459-- extract_path nulls
460SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_false;
461SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_true;
462SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_false;
463SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_true;
464
465-- extract_path operators
466SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f4','f6'];
467SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2'];
468SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','0'];
469SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','1'];
470
471SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f4','f6'];
472SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2'];
473SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','0'];
474SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','1'];
475
476-- corner cases for same
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
498select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> '{}';
499select '[1,2,3]'::jsonb #>> '{}';
500select '"foo"'::jsonb #>> '{}';
501select '42'::jsonb #>> '{}';
502select 'null'::jsonb #>> '{}';
503select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a'];
504select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', null];
505select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a', ''];
506select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b'];
507select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c'];
508select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','b','c','d'];
509select '{"a": {"b":{"c": "foo"}}}'::jsonb #>> array['a','z','c'];
510select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','1','b'];
511select '{"a": [{"b": "c"}, {"b": "cc"}]}'::jsonb #>> array['a','z','b'];
512select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['1','b'];
513select '[{"b": "c"}, {"b": "cc"}]'::jsonb #>> array['z','b'];
514select '[{"b": "c"}, {"b": null}]'::jsonb #>> array['1','b'];
515select '"foo"'::jsonb #>> array['z'];
516select '42'::jsonb #>> array['f2'];
517select '42'::jsonb #>> array['0'];
518
519-- array_elements
520SELECT jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
521SELECT * FROM jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
522SELECT jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
523SELECT * FROM jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
524
525-- populate_record
526CREATE TYPE jbpop AS (a text, b int, c timestamp);
527
528CREATE DOMAIN jsb_int_not_null  AS int     NOT NULL;
529CREATE DOMAIN jsb_int_array_1d  AS int[]   CHECK(array_length(VALUE, 1) = 3);
530CREATE DOMAIN jsb_int_array_2d  AS int[][] CHECK(array_length(VALUE, 2) = 3);
531
532create type jb_unordered_pair as (x int, y int);
533create domain jb_ordered_pair as jb_unordered_pair check((value).x <= (value).y);
534
535CREATE TYPE jsbrec AS (
536	i	int,
537	ia	_int4,
538	ia1	int[],
539	ia2	int[][],
540	ia3	int[][][],
541	ia1d	jsb_int_array_1d,
542	ia2d	jsb_int_array_2d,
543	t	text,
544	ta	text[],
545	c	char(10),
546	ca	char(10)[],
547	ts	timestamp,
548	js	json,
549	jsb	jsonb,
550	jsa	json[],
551	rec	jbpop,
552	reca	jbpop[]
553);
554
555CREATE TYPE jsbrec_i_not_null AS (
556	i	jsb_int_not_null
557);
558
559SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
560SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
561
562SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
563SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
564
565SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":[100,200,false],"x":43.2}') q;
566SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":[100,200,false],"x":43.2}') q;
567SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"c":[100,200,false],"x":43.2}') q;
568
569SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop, '{}') q;
570
571SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"x": 43.2}') q;
572SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"i": null}') q;
573SELECT i FROM jsonb_populate_record(NULL::jsbrec_i_not_null, '{"i": 12345}') q;
574
575SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": null}') q;
576SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": 123}') q;
577SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [1, "2", null, 4]}') q;
578SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1, 2], [3, 4]]}') q;
579SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1], 2]}') q;
580SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": [[1], [2, 3]]}') q;
581SELECT ia FROM jsonb_populate_record(NULL::jsbrec, '{"ia": "{1,2,3}"}') q;
582
583SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": null}') q;
584SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": 123}') q;
585SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": [1, "2", null, 4]}') q;
586SELECT ia1 FROM jsonb_populate_record(NULL::jsbrec, '{"ia1": [[1, 2, 3]]}') q;
587
588SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": null}') q;
589SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": 123}') q;
590SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": [1, "2", null, 4]}') q;
591SELECT ia1d FROM jsonb_populate_record(NULL::jsbrec, '{"ia1d": [1, "2", null]}') q;
592
593SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [1, "2", null, 4]}') q;
594SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], [null, 4]]}') q;
595SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[], []]}') q;
596SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], [3]]}') q;
597SELECT ia2 FROM jsonb_populate_record(NULL::jsbrec, '{"ia2": [[1, 2], 3, 4]}') q;
598
599SELECT ia2d FROM jsonb_populate_record(NULL::jsbrec, '{"ia2d": [[1, "2"], [null, 4]]}') q;
600SELECT ia2d FROM jsonb_populate_record(NULL::jsbrec, '{"ia2d": [[1, "2", 3], [null, 5, 6]]}') q;
601
602SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [1, "2", null, 4]}') q;
603SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [[1, 2], [null, 4]]}') q;
604SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[], []], [[], []], [[], []] ]}') q;
605SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2]], [[3, 4]] ]}') q;
606SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2], [3, 4]], [[5, 6], [7, 8]] ]}') q;
607SELECT ia3 FROM jsonb_populate_record(NULL::jsbrec, '{"ia3": [ [[1, 2], [3, 4]], [[5, 6], [7, 8], [9, 10]] ]}') q;
608
609SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": null}') q;
610SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": 123}') q;
611SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": [1, "2", null, 4]}') q;
612SELECT ta FROM jsonb_populate_record(NULL::jsbrec, '{"ta": [[1, 2, 3], {"k": "v"}]}') q;
613
614SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": null}') q;
615SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaa"}') q;
616SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaaaaaaaaa"}') q;
617SELECT c FROM jsonb_populate_record(NULL::jsbrec, '{"c": "aaaaaaaaaaaaa"}') q;
618
619SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": null}') q;
620SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": 123}') q;
621SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": [1, "2", null, 4]}') q;
622SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": ["aaaaaaaaaaaaaaaa"]}') q;
623SELECT ca FROM jsonb_populate_record(NULL::jsbrec, '{"ca": [[1, 2, 3], {"k": "v"}]}') q;
624
625SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": null}') q;
626SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": true}') q;
627SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": 123.45}') q;
628SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": "123.45"}') q;
629SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": "abc"}') q;
630SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": [123, "123", null, {"key": "value"}]}') q;
631SELECT js FROM jsonb_populate_record(NULL::jsbrec, '{"js": {"a": "bbb", "b": null, "c": 123.45}}') q;
632
633SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": null}') q;
634SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": true}') q;
635SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": 123.45}') q;
636SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": "123.45"}') q;
637SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": "abc"}') q;
638SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": [123, "123", null, {"key": "value"}]}') q;
639SELECT jsb FROM jsonb_populate_record(NULL::jsbrec, '{"jsb": {"a": "bbb", "b": null, "c": 123.45}}') q;
640
641SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": null}') q;
642SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": 123}') q;
643SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": [1, "2", null, 4]}') q;
644SELECT jsa FROM jsonb_populate_record(NULL::jsbrec, '{"jsa": ["aaa", null, [1, 2, "3", {}], { "k" : "v" }]}') q;
645
646SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": 123}') q;
647SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": [1, 2]}') q;
648SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2}}') q;
649SELECT rec FROM jsonb_populate_record(NULL::jsbrec, '{"rec": "(abc,42,01.02.2003)"}') q;
650
651SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": 123}') q;
652SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": [1, 2]}') q;
653SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": [{"a": "abc", "b": 456}, null, {"c": "01.02.2003", "x": 43.2}]}') q;
654SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": ["(abc,42,01.02.2003)"]}') q;
655SELECT reca FROM jsonb_populate_record(NULL::jsbrec, '{"reca": "{\"(abc,42,01.02.2003)\"}"}') q;
656
657SELECT rec FROM jsonb_populate_record(
658	row(NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,
659		row('x',3,'2012-12-31 15:30:56')::jbpop,NULL)::jsbrec,
660	'{"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2}}'
661) q;
662
663-- anonymous record type
664SELECT jsonb_populate_record(null::record, '{"x": 0, "y": 1}');
665SELECT jsonb_populate_record(row(1,2), '{"f1": 0, "f2": 1}');
666SELECT * FROM
667  jsonb_populate_record(null::record, '{"x": 776}') AS (x int, y int);
668
669-- composite domain
670SELECT jsonb_populate_record(null::jb_ordered_pair, '{"x": 0, "y": 1}');
671SELECT jsonb_populate_record(row(1,2)::jb_ordered_pair, '{"x": 0}');
672SELECT jsonb_populate_record(row(1,2)::jb_ordered_pair, '{"x": 1, "y": 0}');
673
674-- populate_recordset
675SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
676SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
677SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
678SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
679SELECT * 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;
680SELECT * 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;
681
682SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
683SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
684SELECT * 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;
685
686-- anonymous record type
687SELECT jsonb_populate_recordset(null::record, '[{"x": 0, "y": 1}]');
688SELECT jsonb_populate_recordset(row(1,2), '[{"f1": 0, "f2": 1}]');
689SELECT i, jsonb_populate_recordset(row(i,50), '[{"f1":"42"},{"f2":"43"}]')
690FROM (VALUES (1),(2)) v(i);
691SELECT * FROM
692  jsonb_populate_recordset(null::record, '[{"x": 776}]') AS (x int, y int);
693
694-- empty array is a corner case
695SELECT jsonb_populate_recordset(null::record, '[]');
696SELECT jsonb_populate_recordset(row(1,2), '[]');
697SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[]') q;
698SELECT * FROM
699  jsonb_populate_recordset(null::record, '[]') AS (x int, y int);
700
701-- composite domain
702SELECT jsonb_populate_recordset(null::jb_ordered_pair, '[{"x": 0, "y": 1}]');
703SELECT jsonb_populate_recordset(row(1,2)::jb_ordered_pair, '[{"x": 0}, {"y": 3}]');
704SELECT jsonb_populate_recordset(row(1,2)::jb_ordered_pair, '[{"x": 1, "y": 0}]');
705
706-- negative cases where the wrong record type is supplied
707select * from jsonb_populate_recordset(row(0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
708select * from jsonb_populate_recordset(row(0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
709select * from jsonb_populate_recordset(row(0::int,0::int,0::int),'[{"a":"1","b":"2"},{"a":"3"}]') q (a text, b text);
710select * from jsonb_populate_recordset(row(1000000000::int,50::int),'[{"b":"2"},{"a":"3"}]') q (a text, b text);
711
712-- jsonb_to_record and jsonb_to_recordset
713
714select * from jsonb_to_record('{"a":1,"b":"foo","c":"bar"}')
715    as x(a int, b text, d text);
716
717select * from jsonb_to_recordset('[{"a":1,"b":"foo","d":false},{"a":2,"b":"bar","c":true}]')
718    as x(a int, b text, c boolean);
719
720select *, c is null as c_is_null
721from 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)
722    as t(a int, b jsonb, c text, x int, ca char(5)[], ia int[][], r jbpop);
723
724select *, c is null as c_is_null
725from jsonb_to_recordset('[{"a":1, "b":{"c":16, "d":2}, "x":8}]'::jsonb)
726    as t(a int, b jsonb, c text, x int);
727
728select * from jsonb_to_record('{"ia": null}') as x(ia _int4);
729select * from jsonb_to_record('{"ia": 123}') as x(ia _int4);
730select * from jsonb_to_record('{"ia": [1, "2", null, 4]}') as x(ia _int4);
731select * from jsonb_to_record('{"ia": [[1, 2], [3, 4]]}') as x(ia _int4);
732select * from jsonb_to_record('{"ia": [[1], 2]}') as x(ia _int4);
733select * from jsonb_to_record('{"ia": [[1], [2, 3]]}') as x(ia _int4);
734
735select * from jsonb_to_record('{"ia2": [1, 2, 3]}') as x(ia2 int[][]);
736select * from jsonb_to_record('{"ia2": [[1, 2], [3, 4]]}') as x(ia2 int4[][]);
737select * from jsonb_to_record('{"ia2": [[[1], [2], [3]]]}') as x(ia2 int4[][]);
738
739select * from jsonb_to_record('{"out": {"key": 1}}') as x(out json);
740select * from jsonb_to_record('{"out": [{"key": 1}]}') as x(out json);
741select * from jsonb_to_record('{"out": "{\"key\": 1}"}') as x(out json);
742select * from jsonb_to_record('{"out": {"key": 1}}') as x(out jsonb);
743select * from jsonb_to_record('{"out": [{"key": 1}]}') as x(out jsonb);
744select * from jsonb_to_record('{"out": "{\"key\": 1}"}') as x(out jsonb);
745
746-- test type info caching in jsonb_populate_record()
747CREATE TEMP TABLE jsbpoptest (js jsonb);
748
749INSERT INTO jsbpoptest
750SELECT '{
751	"jsa": [1, "2", null, 4],
752	"rec": {"a": "abc", "c": "01.02.2003", "x": 43.2},
753	"reca": [{"a": "abc", "b": 456}, null, {"c": "01.02.2003", "x": 43.2}]
754}'::jsonb
755FROM generate_series(1, 3);
756
757SELECT (jsonb_populate_record(NULL::jsbrec, js)).* FROM jsbpoptest;
758
759DROP TYPE jsbrec;
760DROP TYPE jsbrec_i_not_null;
761DROP DOMAIN jsb_int_not_null;
762DROP DOMAIN jsb_int_array_1d;
763DROP DOMAIN jsb_int_array_2d;
764DROP DOMAIN jb_ordered_pair;
765DROP TYPE jb_unordered_pair;
766
767-- indexing
768SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
769SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
770SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
771SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
772SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
773SELECT count(*) FROM testjsonb WHERE j ? 'public';
774SELECT count(*) FROM testjsonb WHERE j ? 'bar';
775SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
776SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
777SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
778SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
779SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
780SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
781SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
782SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
783SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
784SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
785SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
786SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
787SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
788SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
789SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
790SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
791SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
792SELECT count(*) FROM testjsonb WHERE j @? '$';
793SELECT count(*) FROM testjsonb WHERE j @? '$.public';
794SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
795
796CREATE INDEX jidx ON testjsonb USING gin (j);
797SET enable_seqscan = off;
798
799SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
800SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
801SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
802SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
803SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
804SELECT count(*) FROM testjsonb WHERE j @> '{"array":["foo"]}';
805SELECT count(*) FROM testjsonb WHERE j @> '{"array":["bar"]}';
806-- exercise GIN_SEARCH_MODE_ALL
807SELECT count(*) FROM testjsonb WHERE j @> '{}';
808SELECT count(*) FROM testjsonb WHERE j ? 'public';
809SELECT count(*) FROM testjsonb WHERE j ? 'bar';
810SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
811SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
812
813EXPLAIN (COSTS OFF)
814SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
815SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
816SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
817SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
818SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
819SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
820SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
821SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
822SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
823SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
824SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
825SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
826SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
827SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
828SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
829SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
830SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
831SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
832EXPLAIN (COSTS OFF)
833SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
834SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
835SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
836SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
837SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
838SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
839SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
840SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
841SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
842SELECT count(*) FROM testjsonb WHERE j @? '$';
843SELECT count(*) FROM testjsonb WHERE j @? '$.public';
844SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
845
846-- array exists - array elements should behave as keys (for GIN index scans too)
847CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
848SELECT count(*) from testjsonb  WHERE j->'array' ? 'bar';
849-- type sensitive array exists - should return no rows (since "exists" only
850-- matches strings that are either object keys or array elements)
851SELECT count(*) from testjsonb  WHERE j->'array' ? '5'::text;
852-- However, a raw scalar is *contained* within the array
853SELECT count(*) from testjsonb  WHERE j->'array' @> '5'::jsonb;
854
855RESET enable_seqscan;
856
857SELECT count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow;
858SELECT key, count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow GROUP BY key ORDER BY count DESC, key;
859
860-- sort/hash
861SELECT count(distinct j) FROM testjsonb;
862SET enable_hashagg = off;
863SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
864SET enable_hashagg = on;
865SET enable_sort = off;
866SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
867SELECT distinct * FROM (values (jsonb '{}' || ''::text),('{}')) v(j);
868SET enable_sort = on;
869
870RESET enable_hashagg;
871RESET enable_sort;
872
873DROP INDEX jidx;
874DROP INDEX jidx_array;
875-- btree
876CREATE INDEX jidx ON testjsonb USING btree (j);
877SET enable_seqscan = off;
878
879SELECT count(*) FROM testjsonb WHERE j > '{"p":1}';
880SELECT count(*) FROM testjsonb WHERE j = '{"pos":98, "line":371, "node":"CBA", "indexed":true}';
881
882--gin path opclass
883DROP INDEX jidx;
884CREATE INDEX jidx ON testjsonb USING gin (j jsonb_path_ops);
885SET enable_seqscan = off;
886
887SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
888SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
889SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
890SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
891SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
892-- exercise GIN_SEARCH_MODE_ALL
893SELECT count(*) FROM testjsonb WHERE j @> '{}';
894
895SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
896SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
897SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
898SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
899SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
900SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
901SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
902SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
903SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
904SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
905SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
906SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
907SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
908
909EXPLAIN (COSTS OFF)
910SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
911SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
912SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
913SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
914SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
915SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
916SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
917SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
918SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
919SELECT count(*) FROM testjsonb WHERE j @? '$';
920SELECT count(*) FROM testjsonb WHERE j @? '$.public';
921SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
922
923RESET enable_seqscan;
924DROP INDEX jidx;
925
926-- nested tests
927SELECT '{"ff":{"a":12,"b":16}}'::jsonb;
928SELECT '{"ff":{"a":12,"b":16},"qq":123}'::jsonb;
929SELECT '{"aa":["a","aaa"],"qq":{"a":12,"b":16,"c":["c1","c2"],"d":{"d1":"d1","d2":"d2","d1":"d3"}}}'::jsonb;
930SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2"],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
931SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2",["c3"],{"c4":4}],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
932SELECT '{"ff":["a","aaa"]}'::jsonb;
933
934SELECT
935  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'ff',
936  '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'qq',
937  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'Y') IS NULL AS f,
938  ('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb ->> 'Y') IS NULL AS t,
939   '{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'x';
940
941-- nested containment
942SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1,2]}';
943SELECT '{"a":[2,1],"c":"b"}'::jsonb @> '{"a":[1,2]}';
944SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":[1,2]}';
945SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":[1,2]}';
946SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
947SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
948SELECT '["a","b"]'::jsonb @> '["a","b","c","b"]';
949SELECT '["a","b","c","b"]'::jsonb @> '["a","b"]';
950SELECT '["a","b","c",[1,2]]'::jsonb @> '["a",[1,2]]';
951SELECT '["a","b","c",[1,2]]'::jsonb @> '["b",[1,2]]';
952
953SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1]}';
954SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[2]}';
955SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[3]}';
956
957SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"c":3}]}';
958SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4}]}';
959SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},3]}';
960SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},1]}';
961
962-- check some corner cases for indexed nested containment (bug #13756)
963create temp table nestjsonb (j jsonb);
964insert into nestjsonb (j) values ('{"a":[["b",{"x":1}],["b",{"x":2}]],"c":3}');
965insert into nestjsonb (j) values ('[[14,2,3]]');
966insert into nestjsonb (j) values ('[1,[14,2,3]]');
967create index on nestjsonb using gin(j jsonb_path_ops);
968
969set enable_seqscan = on;
970set enable_bitmapscan = off;
971select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
972select * from nestjsonb where j @> '{"c":3}';
973select * from nestjsonb where j @> '[[14]]';
974set enable_seqscan = off;
975set enable_bitmapscan = on;
976select * from nestjsonb where j @> '{"a":[[{"x":2}]]}'::jsonb;
977select * from nestjsonb where j @> '{"c":3}';
978select * from nestjsonb where j @> '[[14]]';
979reset enable_seqscan;
980reset enable_bitmapscan;
981
982-- nested object field / array index lookup
983SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'n';
984SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'a';
985SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'b';
986SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'c';
987SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd';
988SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd' -> '1';
989SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'e';
990SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 0; --expecting error
991
992SELECT '["a","b","c",[1,2],null]'::jsonb -> 0;
993SELECT '["a","b","c",[1,2],null]'::jsonb -> 1;
994SELECT '["a","b","c",[1,2],null]'::jsonb -> 2;
995SELECT '["a","b","c",[1,2],null]'::jsonb -> 3;
996SELECT '["a","b","c",[1,2],null]'::jsonb -> 3 -> 1;
997SELECT '["a","b","c",[1,2],null]'::jsonb -> 4;
998SELECT '["a","b","c",[1,2],null]'::jsonb -> 5;
999SELECT '["a","b","c",[1,2],null]'::jsonb -> -1;
1000SELECT '["a","b","c",[1,2],null]'::jsonb -> -5;
1001SELECT '["a","b","c",[1,2],null]'::jsonb -> -6;
1002
1003--nested path extraction
1004SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{0}';
1005SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{a}';
1006SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c}';
1007SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,0}';
1008SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,1}';
1009SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,2}';
1010SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,3}';
1011SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-1}';
1012SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-3}';
1013SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-4}';
1014
1015SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{0}';
1016SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{3}';
1017SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4}';
1018SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4,5}';
1019
1020--nested exists
1021SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'n';
1022SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'a';
1023SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'b';
1024SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'c';
1025SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'd';
1026SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'e';
1027
1028-- jsonb_strip_nulls
1029
1030select jsonb_strip_nulls(null);
1031
1032select jsonb_strip_nulls('1');
1033
1034select jsonb_strip_nulls('"a string"');
1035
1036select jsonb_strip_nulls('null');
1037
1038select jsonb_strip_nulls('[1,2,null,3,4]');
1039
1040select jsonb_strip_nulls('{"a":1,"b":null,"c":[2,null,3],"d":{"e":4,"f":null}}');
1041
1042select jsonb_strip_nulls('[1,{"a":1,"b":null,"c":2},3]');
1043
1044-- an empty object is not null and should not be stripped
1045select jsonb_strip_nulls('{"a": {"b": null, "c": null}, "d": {} }');
1046
1047
1048select jsonb_pretty('{"a": "test", "b": [1, 2, 3], "c": "test3", "d":{"dd": "test4", "dd2":{"ddd": "test5"}}}');
1049select jsonb_pretty('[{"f1":1,"f2":null},2,null,[[{"x":true},6,7],8],3]');
1050select jsonb_pretty('{"a":["b", "c"], "d": {"e":"f"}}');
1051
1052select jsonb_concat('{"d": "test", "a": [1, 2]}', '{"g": "test2", "c": {"c1":1, "c2":2}}');
1053
1054select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
1055select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aq":"l"}';
1056select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aa":"l"}';
1057select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{}';
1058
1059select '["a", "b"]'::jsonb || '["c"]';
1060select '["a", "b"]'::jsonb || '["c", "d"]';
1061select '["c"]' || '["a", "b"]'::jsonb;
1062
1063select '["a", "b"]'::jsonb || '"c"';
1064select '"c"' || '["a", "b"]'::jsonb;
1065
1066select '[]'::jsonb || '["a"]'::jsonb;
1067select '[]'::jsonb || '"a"'::jsonb;
1068select '"b"'::jsonb || '"a"'::jsonb;
1069select '{}'::jsonb || '{"a":"b"}'::jsonb;
1070select '[]'::jsonb || '{"a":"b"}'::jsonb;
1071select '{"a":"b"}'::jsonb || '[]'::jsonb;
1072
1073select '"a"'::jsonb || '{"a":1}';
1074select '{"a":1}' || '"a"'::jsonb;
1075
1076select '[3]'::jsonb || '{}'::jsonb;
1077select '3'::jsonb || '[]'::jsonb;
1078select '3'::jsonb || '4'::jsonb;
1079select '3'::jsonb || '{}'::jsonb;
1080
1081select '["a", "b"]'::jsonb || '{"c":1}';
1082select '{"c": 1}'::jsonb || '["a", "b"]';
1083
1084select '{}'::jsonb || '{"cq":"l", "b":"g", "fg":false}';
1085
1086select pg_column_size('{}'::jsonb || '{}'::jsonb) = pg_column_size('{}'::jsonb);
1087select pg_column_size('{"aa":1}'::jsonb || '{"b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
1088select pg_column_size('{"aa":1, "b":2}'::jsonb || '{}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
1089select pg_column_size('{}'::jsonb || '{"aa":1, "b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb);
1090
1091select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'a');
1092select jsonb_delete('{"a":null , "b":2, "c":3}'::jsonb, 'a');
1093select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'b');
1094select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'c');
1095select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'd');
1096select '{"a":1 , "b":2, "c":3}'::jsonb - 'a';
1097select '{"a":null , "b":2, "c":3}'::jsonb - 'a';
1098select '{"a":1 , "b":2, "c":3}'::jsonb - 'b';
1099select '{"a":1 , "b":2, "c":3}'::jsonb - 'c';
1100select '{"a":1 , "b":2, "c":3}'::jsonb - 'd';
1101select pg_column_size('{"a":1 , "b":2, "c":3}'::jsonb - 'b') = pg_column_size('{"a":1, "b":2}'::jsonb);
1102
1103select '["a","b","c"]'::jsonb - 3;
1104select '["a","b","c"]'::jsonb - 2;
1105select '["a","b","c"]'::jsonb - 1;
1106select '["a","b","c"]'::jsonb - 0;
1107select '["a","b","c"]'::jsonb - -1;
1108select '["a","b","c"]'::jsonb - -2;
1109select '["a","b","c"]'::jsonb - -3;
1110select '["a","b","c"]'::jsonb - -4;
1111
1112select '{"a":1 , "b":2, "c":3}'::jsonb - '{b}'::text[];
1113select '{"a":1 , "b":2, "c":3}'::jsonb - '{c,b}'::text[];
1114select '{"a":1 , "b":2, "c":3}'::jsonb - '{}'::text[];
1115
1116select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '[1,2,3]');
1117select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '[1,2,3]');
1118select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '[1,2,3]');
1119select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '[1,2,3]');
1120
1121select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '{"1": 2}');
1122select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"1": 2}');
1123select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '{"1": 2}');
1124select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '{"1": 2}');
1125
1126select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '"test"');
1127select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"f": "test"}');
1128
1129select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{n}');
1130select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{b,-1}');
1131select jsonb_delete_path('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}', '{d,1,0}');
1132
1133select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{n}';
1134select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1}';
1135select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{b,-1e}'; -- invalid array subscript
1136select '{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb #- '{d,1,0}';
1137
1138
1139-- empty structure and error conditions for delete and replace
1140
1141select '"a"'::jsonb - 'a'; -- error
1142select '{}'::jsonb - 'a';
1143select '[]'::jsonb - 'a';
1144select '"a"'::jsonb - 1; -- error
1145select '{}'::jsonb -  1; -- error
1146select '[]'::jsonb - 1;
1147select '"a"'::jsonb #- '{a}'; -- error
1148select '{}'::jsonb #- '{a}';
1149select '[]'::jsonb #- '{a}';
1150select jsonb_set('"a"','{a}','"b"'); --error
1151select jsonb_set('{}','{a}','"b"', false);
1152select jsonb_set('[]','{1}','"b"', false);
1153select jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0}','[2,3,4]', false);
1154
1155-- jsonb_set adding instead of replacing
1156
1157-- prepend to array
1158select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,-33}','{"foo":123}');
1159-- append to array
1160select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,33}','{"foo":123}');
1161-- check nesting levels addition
1162select jsonb_set('{"a":1,"b":[4,5,[0,1,2],6,7],"c":{"d":4}}','{b,2,33}','{"foo":123}');
1163-- add new key
1164select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{c,e}','{"foo":123}');
1165-- adding doesn't do anything if elements before last aren't present
1166select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,-33}','{"foo":123}');
1167select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,y}','{"foo":123}');
1168-- add to empty object
1169select jsonb_set('{}','{x}','{"foo":123}');
1170--add to empty array
1171select jsonb_set('[]','{0}','{"foo":123}');
1172select jsonb_set('[]','{99}','{"foo":123}');
1173select jsonb_set('[]','{-99}','{"foo":123}');
1174select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"');
1175select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"');
1176select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"');
1177
1178-- jsonb_set_lax
1179
1180\pset null NULL
1181
1182-- pass though non nulls to jsonb_set
1183select jsonb_set_lax('{"a":1,"b":2}','{b}','5') ;
1184select jsonb_set_lax('{"a":1,"b":2}','{d}','6', true) ;
1185-- using the default treatment
1186select jsonb_set_lax('{"a":1,"b":2}','{b}',null);
1187select jsonb_set_lax('{"a":1,"b":2}','{d}',null,true);
1188-- errors
1189select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, null);
1190select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, 'no_such_treatment');
1191-- explicit treatments
1192select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'raise_exception') as raise_exception;
1193select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'return_target') as return_target;
1194select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'delete_key') as delete_key;
1195select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'use_json_null') as use_json_null;
1196
1197\pset null ''
1198
1199-- jsonb_insert
1200select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');
1201select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true);
1202select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"');
1203select jsonb_insert('{"a": {"b": {"c": [0, 1, "test1", "test2"]}}}', '{a, b, c, 2}', '"new_value"', true);
1204select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '{"b": "value"}');
1205select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '["value1", "value2"]');
1206
1207-- edge cases
1208select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"');
1209select jsonb_insert('{"a": [0,1,2]}', '{a, 0}', '"new_value"', true);
1210select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"');
1211select jsonb_insert('{"a": [0,1,2]}', '{a, 2}', '"new_value"', true);
1212select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"');
1213select jsonb_insert('{"a": [0,1,2]}', '{a, -1}', '"new_value"', true);
1214select jsonb_insert('[]', '{1}', '"new_value"');
1215select jsonb_insert('[]', '{1}', '"new_value"', true);
1216select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"');
1217select jsonb_insert('{"a": []}', '{a, 1}', '"new_value"', true);
1218select jsonb_insert('{"a": [0,1,2]}', '{a, 10}', '"new_value"');
1219select jsonb_insert('{"a": [0,1,2]}', '{a, -10}', '"new_value"');
1220
1221-- jsonb_insert should be able to insert new value for objects, but not to replace
1222select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"');
1223select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"', true);
1224
1225select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"');
1226select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"', true);
1227
1228-- jsonb subscript
1229select ('123'::jsonb)['a'];
1230select ('123'::jsonb)[0];
1231select ('123'::jsonb)[NULL];
1232select ('{"a": 1}'::jsonb)['a'];
1233select ('{"a": 1}'::jsonb)[0];
1234select ('{"a": 1}'::jsonb)['not_exist'];
1235select ('{"a": 1}'::jsonb)[NULL];
1236select ('[1, "2", null]'::jsonb)['a'];
1237select ('[1, "2", null]'::jsonb)[0];
1238select ('[1, "2", null]'::jsonb)['1'];
1239select ('[1, "2", null]'::jsonb)[1.0];
1240select ('[1, "2", null]'::jsonb)[2];
1241select ('[1, "2", null]'::jsonb)[3];
1242select ('[1, "2", null]'::jsonb)[-2];
1243select ('[1, "2", null]'::jsonb)[1]['a'];
1244select ('[1, "2", null]'::jsonb)[1][0];
1245select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['b'];
1246select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'];
1247select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'][1];
1248select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d']['a'];
1249select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1'];
1250select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2'];
1251select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2']['a3'];
1252select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'];
1253select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'][2];
1254
1255-- slices are not supported
1256select ('{"a": 1}'::jsonb)['a':'b'];
1257select ('[1, "2", null]'::jsonb)[1:2];
1258select ('[1, "2", null]'::jsonb)[:2];
1259select ('[1, "2", null]'::jsonb)[1:];
1260select ('[1, "2", null]'::jsonb)[:];
1261
1262create TEMP TABLE test_jsonb_subscript (
1263       id int,
1264       test_json jsonb
1265);
1266
1267insert into test_jsonb_subscript values
1268(1, '{}'), -- empty jsonb
1269(2, '{"key": "value"}'); -- jsonb with data
1270
1271-- update empty jsonb
1272update test_jsonb_subscript set test_json['a'] = '1' where id = 1;
1273select * from test_jsonb_subscript;
1274
1275-- update jsonb with some data
1276update test_jsonb_subscript set test_json['a'] = '1' where id = 2;
1277select * from test_jsonb_subscript;
1278
1279-- replace jsonb
1280update test_jsonb_subscript set test_json['a'] = '"test"';
1281select * from test_jsonb_subscript;
1282
1283-- replace by object
1284update test_jsonb_subscript set test_json['a'] = '{"b": 1}'::jsonb;
1285select * from test_jsonb_subscript;
1286
1287-- replace by array
1288update test_jsonb_subscript set test_json['a'] = '[1, 2, 3]'::jsonb;
1289select * from test_jsonb_subscript;
1290
1291-- use jsonb subscription in where clause
1292select * from test_jsonb_subscript where test_json['key'] = '"value"';
1293select * from test_jsonb_subscript where test_json['key_doesnt_exists'] = '"value"';
1294select * from test_jsonb_subscript where test_json['key'] = '"wrong_value"';
1295
1296-- NULL
1297update test_jsonb_subscript set test_json[NULL] = '1';
1298update test_jsonb_subscript set test_json['another_key'] = NULL;
1299select * from test_jsonb_subscript;
1300
1301-- NULL as jsonb source
1302insert into test_jsonb_subscript values (3, NULL);
1303update test_jsonb_subscript set test_json['a'] = '1' where id = 3;
1304select * from test_jsonb_subscript;
1305
1306update test_jsonb_subscript set test_json = NULL where id = 3;
1307update test_jsonb_subscript set test_json[0] = '1';
1308select * from test_jsonb_subscript;
1309
1310-- Fill the gaps logic
1311delete from test_jsonb_subscript;
1312insert into test_jsonb_subscript values (1, '[0]');
1313
1314update test_jsonb_subscript set test_json[5] = '1';
1315select * from test_jsonb_subscript;
1316
1317update test_jsonb_subscript set test_json[-4] = '1';
1318select * from test_jsonb_subscript;
1319
1320update test_jsonb_subscript set test_json[-8] = '1';
1321select * from test_jsonb_subscript;
1322
1323-- keep consistent values position
1324delete from test_jsonb_subscript;
1325insert into test_jsonb_subscript values (1, '[]');
1326
1327update test_jsonb_subscript set test_json[5] = '1';
1328select * from test_jsonb_subscript;
1329
1330-- create the whole path
1331delete from test_jsonb_subscript;
1332insert into test_jsonb_subscript values (1, '{}');
1333update test_jsonb_subscript set test_json['a'][0]['b'][0]['c'] = '1';
1334select * from test_jsonb_subscript;
1335
1336delete from test_jsonb_subscript;
1337insert into test_jsonb_subscript values (1, '{}');
1338update test_jsonb_subscript set test_json['a'][2]['b'][2]['c'][2] = '1';
1339select * from test_jsonb_subscript;
1340
1341-- create the whole path with already existing keys
1342delete from test_jsonb_subscript;
1343insert into test_jsonb_subscript values (1, '{"b": 1}');
1344update test_jsonb_subscript set test_json['a'][0] = '2';
1345select * from test_jsonb_subscript;
1346
1347-- the start jsonb is an object, first subscript is treated as a key
1348delete from test_jsonb_subscript;
1349insert into test_jsonb_subscript values (1, '{}');
1350update test_jsonb_subscript set test_json[0]['a'] = '1';
1351select * from test_jsonb_subscript;
1352
1353-- the start jsonb is an array
1354delete from test_jsonb_subscript;
1355insert into test_jsonb_subscript values (1, '[]');
1356update test_jsonb_subscript set test_json[0]['a'] = '1';
1357update test_jsonb_subscript set test_json[2]['b'] = '2';
1358select * from test_jsonb_subscript;
1359
1360-- overwriting an existing path
1361delete from test_jsonb_subscript;
1362insert into test_jsonb_subscript values (1, '{}');
1363update test_jsonb_subscript set test_json['a']['b'][1] = '1';
1364update test_jsonb_subscript set test_json['a']['b'][10] = '1';
1365select * from test_jsonb_subscript;
1366
1367delete from test_jsonb_subscript;
1368insert into test_jsonb_subscript values (1, '[]');
1369update test_jsonb_subscript set test_json[0][0][0] = '1';
1370update test_jsonb_subscript set test_json[0][0][1] = '1';
1371select * from test_jsonb_subscript;
1372
1373delete from test_jsonb_subscript;
1374insert into test_jsonb_subscript values (1, '{}');
1375update test_jsonb_subscript set test_json['a']['b'][10] = '1';
1376update test_jsonb_subscript set test_json['a'][10][10] = '1';
1377select * from test_jsonb_subscript;
1378
1379-- an empty sub element
1380
1381delete from test_jsonb_subscript;
1382insert into test_jsonb_subscript values (1, '{"a": {}}');
1383update test_jsonb_subscript set test_json['a']['b']['c'][2] = '1';
1384select * from test_jsonb_subscript;
1385
1386delete from test_jsonb_subscript;
1387insert into test_jsonb_subscript values (1, '{"a": []}');
1388update test_jsonb_subscript set test_json['a'][1]['c'][2] = '1';
1389select * from test_jsonb_subscript;
1390
1391-- trying replace assuming a composite object, but it's an element or a value
1392
1393delete from test_jsonb_subscript;
1394insert into test_jsonb_subscript values (1, '{"a": 1}');
1395update test_jsonb_subscript set test_json['a']['b'] = '1';
1396update test_jsonb_subscript set test_json['a']['b']['c'] = '1';
1397update test_jsonb_subscript set test_json['a'][0] = '1';
1398update test_jsonb_subscript set test_json['a'][0]['c'] = '1';
1399update test_jsonb_subscript set test_json['a'][0][0] = '1';
1400
1401-- trying replace assuming a composite object, but it's a raw scalar
1402
1403delete from test_jsonb_subscript;
1404insert into test_jsonb_subscript values (1, 'null');
1405update test_jsonb_subscript set test_json[0] = '1';
1406update test_jsonb_subscript set test_json[0][0] = '1';
1407
1408-- jsonb to tsvector
1409select to_tsvector('{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
1410
1411-- jsonb to tsvector with config
1412select to_tsvector('simple', '{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
1413
1414-- jsonb to tsvector with stop words
1415select to_tsvector('english', '{"a": "aaa in bbb ddd ccc", "b": ["the eee fff ggg"], "c": {"d": "hhh. iii"}}'::jsonb);
1416
1417-- jsonb to tsvector with numeric values
1418select to_tsvector('english', '{"a": "aaa in bbb ddd ccc", "b": 123, "c": 456}'::jsonb);
1419
1420-- jsonb_to_tsvector
1421select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"all"');
1422select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"key"');
1423select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"string"');
1424select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"numeric"');
1425select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"boolean"');
1426select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["string", "numeric"]');
1427
1428select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"all"');
1429select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"key"');
1430select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"string"');
1431select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"numeric"');
1432select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '"boolean"');
1433select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["string", "numeric"]');
1434
1435-- to_tsvector corner cases
1436select to_tsvector('""'::jsonb);
1437select to_tsvector('{}'::jsonb);
1438select to_tsvector('[]'::jsonb);
1439select to_tsvector('null'::jsonb);
1440
1441-- jsonb_to_tsvector corner cases
1442select jsonb_to_tsvector('""'::jsonb, '"all"');
1443select jsonb_to_tsvector('{}'::jsonb, '"all"');
1444select jsonb_to_tsvector('[]'::jsonb, '"all"');
1445select jsonb_to_tsvector('null'::jsonb, '"all"');
1446
1447select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '""');
1448select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '{}');
1449select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '[]');
1450select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, 'null');
1451select jsonb_to_tsvector('english', '{"a": "aaa in bbb", "b": 123, "c": 456, "d": true, "f": false, "g": null}'::jsonb, '["all", null]');
1452
1453-- ts_headline for jsonb
1454select ts_headline('{"a": "aaa bbb", "b": {"c": "ccc ddd fff", "c1": "ccc1 ddd1"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'));
1455select ts_headline('english', '{"a": "aaa bbb", "b": {"c": "ccc ddd fff"}, "d": ["ggg hhh", "iii jjj"]}'::jsonb, tsquery('bbb & ddd & hhh'));
1456select 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 = >');
1457select 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 = >');
1458
1459-- corner cases for ts_headline with jsonb
1460select ts_headline('null'::jsonb, tsquery('aaa & bbb'));
1461select ts_headline('{}'::jsonb, tsquery('aaa & bbb'));
1462select ts_headline('[]'::jsonb, tsquery('aaa & bbb'));
1463
1464-- casts
1465select 'true'::jsonb::bool;
1466select '[]'::jsonb::bool;
1467select '1.0'::jsonb::float;
1468select '[1.0]'::jsonb::float;
1469select '12345'::jsonb::int4;
1470select '"hello"'::jsonb::int4;
1471select '12345'::jsonb::numeric;
1472select '{}'::jsonb::numeric;
1473select '12345.05'::jsonb::numeric;
1474select '12345.05'::jsonb::float4;
1475select '12345.05'::jsonb::float8;
1476select '12345.05'::jsonb::int2;
1477select '12345.05'::jsonb::int4;
1478select '12345.05'::jsonb::int8;
1479select '12345.0000000000000000000000000000000000000000000005'::jsonb::numeric;
1480select '12345.0000000000000000000000000000000000000000000005'::jsonb::float4;
1481select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
1482select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
1483select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
1484select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
1485