mirror of
https://github.com/zebrajr/postgres.git
synced 2025-12-08 07:38:44 +01:00
populate_recordset_object_start() improperly created a new hash table (overwriting the link to the existing one) if called at nest levels greater than one. This resulted in previous fields not appearing in the final output, as reported by Matti Hameister in bug #10728. In 9.4 the problem also affects json_to_recordset. This perhaps missed detection earlier because the default behavior is to throw an error for nested objects: you have to pass use_json_as_text = true to see the problem. In addition, fix query-lifespan leakage of the hashtable created by json_populate_record(). This is pretty much the same problem recently fixed in dblink: creating an intended-to-be-temporary context underneath the executor's per-tuple context isn't enough to make it go away at the end of the tuple cycle, because MemoryContextReset is not MemoryContextResetAndDeleteChildren. Michael Paquier and Tom Lane
316 lines
12 KiB
SQL
316 lines
12 KiB
SQL
-- Strings.
|
|
SELECT '""'::json; -- OK.
|
|
SELECT $$''$$::json; -- ERROR, single quotes are not allowed
|
|
SELECT '"abc"'::json; -- OK
|
|
SELECT '"abc'::json; -- ERROR, quotes not closed
|
|
SELECT '"abc
|
|
def"'::json; -- ERROR, unescaped newline in string constant
|
|
SELECT '"\n\"\\"'::json; -- OK, legal escapes
|
|
SELECT '"\v"'::json; -- ERROR, not a valid JSON escape
|
|
SELECT '"\u"'::json; -- ERROR, incomplete escape
|
|
SELECT '"\u00"'::json; -- ERROR, incomplete escape
|
|
SELECT '"\u000g"'::json; -- ERROR, g is not a hex digit
|
|
SELECT '"\u0000"'::json; -- OK, legal escape
|
|
SELECT '"\uaBcD"'::json; -- OK, uppercase and lower case both OK
|
|
|
|
-- Numbers.
|
|
SELECT '1'::json; -- OK
|
|
SELECT '0'::json; -- OK
|
|
SELECT '01'::json; -- ERROR, not valid according to JSON spec
|
|
SELECT '0.1'::json; -- OK
|
|
SELECT '9223372036854775808'::json; -- OK, even though it's too large for int8
|
|
SELECT '1e100'::json; -- OK
|
|
SELECT '1.3e100'::json; -- OK
|
|
SELECT '1f2'::json; -- ERROR
|
|
SELECT '0.x1'::json; -- ERROR
|
|
SELECT '1.3ex100'::json; -- ERROR
|
|
|
|
-- Arrays.
|
|
SELECT '[]'::json; -- OK
|
|
SELECT '[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]'::json; -- OK
|
|
SELECT '[1,2]'::json; -- OK
|
|
SELECT '[1,2,]'::json; -- ERROR, trailing comma
|
|
SELECT '[1,2'::json; -- ERROR, no closing bracket
|
|
SELECT '[1,[2]'::json; -- ERROR, no closing bracket
|
|
|
|
-- Objects.
|
|
SELECT '{}'::json; -- OK
|
|
SELECT '{"abc"}'::json; -- ERROR, no value
|
|
SELECT '{"abc":1}'::json; -- OK
|
|
SELECT '{1:"abc"}'::json; -- ERROR, keys must be strings
|
|
SELECT '{"abc",1}'::json; -- ERROR, wrong separator
|
|
SELECT '{"abc"=1}'::json; -- ERROR, totally wrong separator
|
|
SELECT '{"abc"::1}'::json; -- ERROR, another wrong separator
|
|
SELECT '{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}'::json; -- OK
|
|
SELECT '{"abc":1:2}'::json; -- ERROR, colon in wrong spot
|
|
SELECT '{"abc":1,3}'::json; -- ERROR, no value
|
|
|
|
-- Miscellaneous stuff.
|
|
SELECT 'true'::json; -- OK
|
|
SELECT 'false'::json; -- OK
|
|
SELECT 'null'::json; -- OK
|
|
SELECT ' true '::json; -- OK, even with extra whitespace
|
|
SELECT 'true false'::json; -- ERROR, too many values
|
|
SELECT 'true, false'::json; -- ERROR, too many values
|
|
SELECT 'truf'::json; -- ERROR, not a keyword
|
|
SELECT 'trues'::json; -- ERROR, not a keyword
|
|
SELECT ''::json; -- ERROR, no value
|
|
SELECT ' '::json; -- ERROR, no value
|
|
|
|
--constructors
|
|
-- array_to_json
|
|
|
|
SELECT array_to_json(array(select 1 as a));
|
|
SELECT array_to_json(array_agg(q),false) from (select x as b, x * 2 as c from generate_series(1,3) x) q;
|
|
SELECT array_to_json(array_agg(q),true) from (select x as b, x * 2 as c from generate_series(1,3) x) q;
|
|
SELECT array_to_json(array_agg(q),false)
|
|
FROM ( SELECT $$a$$ || x AS b, y AS c,
|
|
ARRAY[ROW(x.*,ARRAY[1,2,3]),
|
|
ROW(y.*,ARRAY[4,5,6])] AS z
|
|
FROM generate_series(1,2) x,
|
|
generate_series(4,5) y) q;
|
|
SELECT array_to_json(array_agg(x),false) from generate_series(5,10) x;
|
|
SELECT array_to_json('{{1,5},{99,100}}'::int[]);
|
|
|
|
-- row_to_json
|
|
SELECT row_to_json(row(1,'foo'));
|
|
|
|
SELECT row_to_json(q)
|
|
FROM (SELECT $$a$$ || x AS b,
|
|
y AS c,
|
|
ARRAY[ROW(x.*,ARRAY[1,2,3]),
|
|
ROW(y.*,ARRAY[4,5,6])] AS z
|
|
FROM generate_series(1,2) x,
|
|
generate_series(4,5) y) q;
|
|
|
|
SELECT row_to_json(q,true)
|
|
FROM (SELECT $$a$$ || x AS b,
|
|
y AS c,
|
|
ARRAY[ROW(x.*,ARRAY[1,2,3]),
|
|
ROW(y.*,ARRAY[4,5,6])] AS z
|
|
FROM generate_series(1,2) x,
|
|
generate_series(4,5) y) q;
|
|
|
|
CREATE TEMP TABLE rows AS
|
|
SELECT x, 'txt' || x as y
|
|
FROM generate_series(1,3) AS x;
|
|
|
|
SELECT row_to_json(q,true)
|
|
FROM rows q;
|
|
|
|
SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),false);
|
|
|
|
--json_agg
|
|
|
|
SELECT json_agg(q)
|
|
FROM ( SELECT $$a$$ || x AS b, y AS c,
|
|
ARRAY[ROW(x.*,ARRAY[1,2,3]),
|
|
ROW(y.*,ARRAY[4,5,6])] AS z
|
|
FROM generate_series(1,2) x,
|
|
generate_series(4,5) y) q;
|
|
|
|
SELECT json_agg(q)
|
|
FROM rows q;
|
|
|
|
-- non-numeric output
|
|
SELECT row_to_json(q)
|
|
FROM (SELECT 'NaN'::float8 AS "float8field") q;
|
|
|
|
SELECT row_to_json(q)
|
|
FROM (SELECT 'Infinity'::float8 AS "float8field") q;
|
|
|
|
SELECT row_to_json(q)
|
|
FROM (SELECT '-Infinity'::float8 AS "float8field") q;
|
|
|
|
-- json input
|
|
SELECT row_to_json(q)
|
|
FROM (SELECT '{"a":1,"b": [2,3,4,"d","e","f"],"c":{"p":1,"q":2}}'::json AS "jsonfield") q;
|
|
|
|
|
|
-- json extraction functions
|
|
|
|
CREATE TEMP TABLE test_json (
|
|
json_type text,
|
|
test_json json
|
|
);
|
|
|
|
INSERT INTO test_json VALUES
|
|
('scalar','"a scalar"'),
|
|
('array','["zero", "one","two",null,"four","five"]'),
|
|
('object','{"field1":"val1","field2":"val2","field3":null}');
|
|
|
|
SELECT test_json -> 'x'
|
|
FROM test_json
|
|
WHERE json_type = 'scalar';
|
|
|
|
SELECT test_json -> 'x'
|
|
FROM test_json
|
|
WHERE json_type = 'array';
|
|
|
|
SELECT test_json -> 'x'
|
|
FROM test_json
|
|
WHERE json_type = 'object';
|
|
|
|
SELECT test_json->'field2'
|
|
FROM test_json
|
|
WHERE json_type = 'object';
|
|
|
|
SELECT test_json->>'field2'
|
|
FROM test_json
|
|
WHERE json_type = 'object';
|
|
|
|
SELECT test_json -> 2
|
|
FROM test_json
|
|
WHERE json_type = 'scalar';
|
|
|
|
SELECT test_json -> 2
|
|
FROM test_json
|
|
WHERE json_type = 'array';
|
|
|
|
SELECT test_json -> 2
|
|
FROM test_json
|
|
WHERE json_type = 'object';
|
|
|
|
SELECT test_json->>2
|
|
FROM test_json
|
|
WHERE json_type = 'array';
|
|
|
|
SELECT json_object_keys(test_json)
|
|
FROM test_json
|
|
WHERE json_type = 'scalar';
|
|
|
|
SELECT json_object_keys(test_json)
|
|
FROM test_json
|
|
WHERE json_type = 'array';
|
|
|
|
SELECT json_object_keys(test_json)
|
|
FROM test_json
|
|
WHERE json_type = 'object';
|
|
|
|
-- nulls
|
|
|
|
select (test_json->'field3') is null as expect_false
|
|
from test_json
|
|
where json_type = 'object';
|
|
|
|
select (test_json->>'field3') is null as expect_true
|
|
from test_json
|
|
where json_type = 'object';
|
|
|
|
select (test_json->3) is null as expect_false
|
|
from test_json
|
|
where json_type = 'array';
|
|
|
|
select (test_json->>3) is null as expect_true
|
|
from test_json
|
|
where json_type = 'array';
|
|
|
|
|
|
-- array length
|
|
|
|
SELECT json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
|
|
|
|
SELECT json_array_length('[]');
|
|
|
|
SELECT json_array_length('{"f1":1,"f2":[5,6]}');
|
|
|
|
SELECT json_array_length('4');
|
|
|
|
-- each
|
|
|
|
select json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
|
|
select * from json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
|
|
|
|
select json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
|
|
select * from json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
|
|
|
|
-- extract_path, extract_path_as_text
|
|
|
|
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
|
|
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
|
|
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
|
|
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
|
|
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
|
|
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
|
|
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
|
|
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
|
|
|
|
-- extract_path nulls
|
|
|
|
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_false;
|
|
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_true;
|
|
select json_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') is null as expect_false;
|
|
select json_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') is null as expect_true;
|
|
|
|
-- extract_path operators
|
|
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f4','f6'];
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2'];
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','0'];
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','1'];
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f4','f6'];
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2'];
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','0'];
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','1'];
|
|
|
|
-- same using array literals
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f4,f6}';
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2}';
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,0}';
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,1}';
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f4,f6}';
|
|
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2}';
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,0}';
|
|
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
|
|
|
|
-- array_elements
|
|
|
|
select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
|
|
select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
|
|
|
|
-- populate_record
|
|
create type jpop as (a text, b int, c timestamp);
|
|
|
|
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}') q;
|
|
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}') q;
|
|
|
|
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}', true) q;
|
|
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}', true) q;
|
|
|
|
select * from json_populate_record(null::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
|
|
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
|
|
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"c":[100,200,false],"x":43.2}', true) q;
|
|
|
|
-- populate_recordset
|
|
|
|
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
|
|
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
|
|
|
|
create type jpop2 as (a int, b json, c int, d int);
|
|
select * from json_populate_recordset(null::jpop2, '[{"a":2,"c":3,"b":{"z":4},"d":6}]',true) q;
|
|
|
|
-- using the default use_json_as_text argument
|
|
|
|
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
|
|
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
|
|
|
|
-- handling of unicode surrogate pairs
|
|
|
|
select json '{ "a": "\ud83d\ude04\ud83d\udc36" }' -> 'a' as correct_in_utf8;
|
|
select json '{ "a": "\ud83d\ud83d" }' -> 'a'; -- 2 high surrogates in a row
|
|
select json '{ "a": "\ude04\ud83d" }' -> 'a'; -- surrogates in wrong order
|
|
select json '{ "a": "\ud83dX" }' -> 'a'; -- orphan high surrogate
|
|
select json '{ "a": "\ude04X" }' -> 'a'; -- orphan low surrogate
|
|
|
|
--handling of simple unicode escapes
|
|
|
|
select json '{ "a": "the Copyright \u00a9 sign" }' ->> 'a' as correct_in_utf8;
|
|
select json '{ "a": "dollar \u0024 character" }' ->> 'a' as correct_everywhere;
|
|
select json '{ "a": "null \u0000 escape" }' ->> 'a' as not_unescaped;
|