Commit 676887a3 authored by Alexander Korotkov's avatar Alexander Korotkov

Implementation of subscripting for jsonb

Subscripting for jsonb does not support slices, does not have a limit for the
number of subscripts, and an assignment expects a replace value to have jsonb
type.  There is also one functional difference between assignment via
subscripting and assignment via jsonb_set().  When an original jsonb container
is NULL, the subscripting replaces it with an empty jsonb and proceeds with
an assignment.

For the sake of code reuse, we rearrange some parts of jsonb functionality
to allow the usage of the same functions for jsonb_set and assign subscripting
operation.

The original idea belongs to Oleg Bartunov.

Catversion is bumped.

Discussion: https://postgr.es/m/CA%2Bq6zcV8qvGcDXurwwgUbwACV86Th7G80pnubg42e-p9gsSf%3Dg%40mail.gmail.com
Discussion: https://postgr.es/m/CA%2Bq6zcX3mdxGCgdThzuySwH-ApyHHM-G4oB1R0fn0j2hZqqkLQ%40mail.gmail.com
Discussion: https://postgr.es/m/CA%2Bq6zcVDuGBv%3DM0FqBYX8DPebS3F_0KQ6OVFobGJPM507_SZ_w%40mail.gmail.com
Discussion: https://postgr.es/m/CA%2Bq6zcVovR%2BXY4mfk-7oNk-rF91gH0PebnNfuUjuuDsyHjOcVA%40mail.gmail.com
Author: Dmitry Dolgov
Reviewed-by: Tom Lane, Arthur Zakirov, Pavel Stehule, Dian M Fay
Reviewed-by: Andrew Dunstan, Chapman Flack, Merlin Moncure, Peter Geoghegan
Reviewed-by: Alvaro Herrera, Jim Nasby, Josh Berkus, Victor Wagner
Reviewed-by: Aleksander Alekseev, Robert Haas, Oleg Bartunov
parent dc43492e
......@@ -602,6 +602,57 @@ SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @> '{"tags": ["qu
</para>
</sect2>
<sect2 id="jsonb-subscripting">
<title><type>jsonb</type> Subscripting</title>
<para>
The <type>jsonb</type> data type supports array-style subscripting expressions
to extract and modify elements. Nested values can be indicated by chaining
subscripting expressions, following the same rules as the <literal>path</literal>
argument in the <literal>jsonb_set</literal> function. If a <type>jsonb</type>
value is an array, numeric subscripts start at zero, and negative integers count
backwards from the last element of the array. Slice expressions are not supported.
The result of a subscripting expression is always of the jsonb data type.
</para>
<para>
An example of subscripting syntax:
<programlisting>
-- Extract object value by key
SELECT ('{"a": 1}'::jsonb)['a'];
-- Extract nested object value by key path
SELECT ('{"a": {"b": {"c": 1}}}'::jsonb)['a']['b']['c'];
-- Extract array element by index
SELECT ('[1, "2", null]'::jsonb)[1];
-- Update object value by key. Note the quotes around '1': the assigned
-- value must be of the jsonb type as well
UPDATE table_name SET jsonb_field['key'] = '1';
-- Filter records using a WHERE clause with subscripting. Since the result of
-- subscripting is jsonb, the value we compare it against must also be jsonb.
-- The double quotes make "value" also a valid jsonb string.
SELECT * FROM table_name WHERE jsonb_field['key'] = '"value"';
</programlisting>
<type>jsonb</type> assignment via subscripting handles a few edge cases
differently from <literal>jsonb_set</literal>. When a source <type>jsonb</type>
is <literal>NULL</literal>, assignment via subscripting will proceed as if
it was an empty JSON object:
<programlisting>
-- Where jsonb_field was NULL, it is now {"a": 1}
UPDATE table_name SET jsonb_field['a'] = '1';
-- Where jsonb_field was NULL, it is now [1]
UPDATE table_name SET jsonb_field[0] = '1';
</programlisting>
</para>
</sect2>
<sect2>
<title>Transforms</title>
......
......@@ -50,6 +50,7 @@ OBJS = \
jsonb_op.o \
jsonb_util.o \
jsonfuncs.o \
jsonbsubs.o \
jsonpath.o \
jsonpath_exec.o \
jsonpath_gram.o \
......
......@@ -68,18 +68,25 @@ static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
JsonbIteratorToken seq,
JsonbValue *scalarVal);
void
JsonbToJsonbValue(Jsonb *jsonb, JsonbValue *val)
{
val->type = jbvBinary;
val->val.binary.data = &jsonb->root;
val->val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
}
/*
* Turn an in-memory JsonbValue into a Jsonb for on-disk storage.
*
* There isn't a JsonbToJsonbValue(), because generally we find it more
* convenient to directly iterate through the Jsonb representation and only
* really convert nested scalar values. JsonbIteratorNext() does this, so that
* clients of the iteration code don't have to directly deal with the binary
* representation (JsonbDeepContains() is a notable exception, although all
* exceptions are internal to this module). In general, functions that accept
* a JsonbValue argument are concerned with the manipulation of scalar values,
* or simple containers of scalar values, where it would be inconvenient to
* deal with a great amount of other state.
* Generally we find it more convenient to directly iterate through the Jsonb
* representation and only really convert nested scalar values.
* JsonbIteratorNext() does this, so that clients of the iteration code don't
* have to directly deal with the binary representation (JsonbDeepContains() is
* a notable exception, although all exceptions are internal to this module).
* In general, functions that accept a JsonbValue argument are concerned with
* the manipulation of scalar values, or simple containers of scalar values,
* where it would be inconvenient to deal with a great amount of other state.
*/
Jsonb *
JsonbValueToJsonb(JsonbValue *val)
......@@ -563,6 +570,30 @@ pushJsonbValue(JsonbParseState **pstate, JsonbIteratorToken seq,
JsonbValue *res = NULL;
JsonbValue v;
JsonbIteratorToken tok;
int i;
if (jbval && (seq == WJB_ELEM || seq == WJB_VALUE) && jbval->type == jbvObject)
{
pushJsonbValue(pstate, WJB_BEGIN_OBJECT, NULL);
for (i = 0; i < jbval->val.object.nPairs; i++)
{
pushJsonbValue(pstate, WJB_KEY, &jbval->val.object.pairs[i].key);
pushJsonbValue(pstate, WJB_VALUE, &jbval->val.object.pairs[i].value);
}
return pushJsonbValue(pstate, WJB_END_OBJECT, NULL);
}
if (jbval && (seq == WJB_ELEM || seq == WJB_VALUE) && jbval->type == jbvArray)
{
pushJsonbValue(pstate, WJB_BEGIN_ARRAY, NULL);
for (i = 0; i < jbval->val.array.nElems; i++)
{
pushJsonbValue(pstate, WJB_ELEM, &jbval->val.array.elems[i]);
}
return pushJsonbValue(pstate, WJB_END_ARRAY, NULL);
}
if (!jbval || (seq != WJB_ELEM && seq != WJB_VALUE) ||
jbval->type != jbvBinary)
......@@ -573,9 +604,30 @@ pushJsonbValue(JsonbParseState **pstate, JsonbIteratorToken seq,
/* unpack the binary and add each piece to the pstate */
it = JsonbIteratorInit(jbval->val.binary.data);
if ((jbval->val.binary.data->header & JB_FSCALAR) && *pstate)
{
tok = JsonbIteratorNext(&it, &v, true);
Assert(tok == WJB_BEGIN_ARRAY);
Assert(v.type == jbvArray && v.val.array.rawScalar);
tok = JsonbIteratorNext(&it, &v, true);
Assert(tok == WJB_ELEM);
res = pushJsonbValueScalar(pstate, seq, &v);
tok = JsonbIteratorNext(&it, &v, true);
Assert(tok == WJB_END_ARRAY);
Assert(it == NULL);
return res;
}
while ((tok = JsonbIteratorNext(&it, &v, false)) != WJB_DONE)
res = pushJsonbValueScalar(pstate, tok,
tok < WJB_BEGIN_ARRAY ? &v : NULL);
tok < WJB_BEGIN_ARRAY ||
(tok == WJB_BEGIN_ARRAY &&
v.val.array.rawScalar) ? &v : NULL);
return res;
}
......
This diff is collapsed.
This diff is collapsed.
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 202101181
#define CATALOG_VERSION_NO 202101311
#endif
......@@ -11300,6 +11300,10 @@
{ oid => '9256', descr => 'raw array subscripting support',
proname => 'raw_array_subscript_handler', prorettype => 'internal',
proargtypes => 'internal', prosrc => 'raw_array_subscript_handler' },
# type subscripting support
{ oid => '6098', descr => 'jsonb subscripting logic',
proname => 'jsonb_subscript_handler', prorettype => 'internal',
proargtypes => 'internal', prosrc => 'jsonb_subscript_handler' },
# collation management functions
{ oid => '3445', descr => 'import collations from operating system',
......
......@@ -444,7 +444,8 @@
{ oid => '3802', array_type_oid => '3807', descr => 'Binary JSON',
typname => 'jsonb', typlen => '-1', typbyval => 'f', typcategory => 'U',
typinput => 'jsonb_in', typoutput => 'jsonb_out', typreceive => 'jsonb_recv',
typsend => 'jsonb_send', typalign => 'i', typstorage => 'x' },
typsend => 'jsonb_send', typalign => 'i', typstorage => 'x',
typsubscript => 'jsonb_subscript_handler' },
{ oid => '4072', array_type_oid => '4073', descr => 'JSON path',
typname => 'jsonpath', typlen => '-1', typbyval => 'f', typcategory => 'U',
typinput => 'jsonpath_in', typoutput => 'jsonpath_out',
......
......@@ -392,6 +392,7 @@ extern JsonbValue *pushJsonbValue(JsonbParseState **pstate,
extern JsonbIterator *JsonbIteratorInit(JsonbContainer *container);
extern JsonbIteratorToken JsonbIteratorNext(JsonbIterator **it, JsonbValue *val,
bool skipNested);
extern void JsonbToJsonbValue(Jsonb *jsonb, JsonbValue *val);
extern Jsonb *JsonbValueToJsonb(JsonbValue *val);
extern bool JsonbDeepContains(JsonbIterator **val,
JsonbIterator **mContained);
......@@ -407,5 +408,8 @@ extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
extern const char *JsonbTypeName(JsonbValue *jb);
extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
JsonbValue *newval);
extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
bool *isnull, bool as_text);
#endif /* __JSONB_H__ */
......@@ -4599,7 +4599,7 @@ select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'use_
{"a": 1, "b": null}
(1 row)
\pset null
\pset null ''
-- jsonb_insert
select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');
jsonb_insert
......@@ -4729,6 +4729,276 @@ HINT: Try using the function jsonb_set to replace key value.
select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"', true);
ERROR: cannot replace existing key
HINT: Try using the function jsonb_set to replace key value.
-- jsonb subscript
select ('123'::jsonb)['a'];
jsonb
-------
(1 row)
select ('123'::jsonb)[0];
jsonb
-------
(1 row)
select ('123'::jsonb)[NULL];
jsonb
-------
(1 row)
select ('{"a": 1}'::jsonb)['a'];
jsonb
-------
1
(1 row)
select ('{"a": 1}'::jsonb)[0];
jsonb
-------
(1 row)
select ('{"a": 1}'::jsonb)['not_exist'];
jsonb
-------
(1 row)
select ('{"a": 1}'::jsonb)[NULL];
jsonb
-------
(1 row)
select ('[1, "2", null]'::jsonb)['a'];
jsonb
-------
(1 row)
select ('[1, "2", null]'::jsonb)[0];
jsonb
-------
1
(1 row)
select ('[1, "2", null]'::jsonb)['1'];
jsonb
-------
"2"
(1 row)
select ('[1, "2", null]'::jsonb)[1.0];
ERROR: subscript type is not supported
LINE 1: select ('[1, "2", null]'::jsonb)[1.0];
^
HINT: Jsonb subscript must be coerced to either integer or text
select ('[1, "2", null]'::jsonb)[2];
jsonb
-------
null
(1 row)
select ('[1, "2", null]'::jsonb)[3];
jsonb
-------
(1 row)
select ('[1, "2", null]'::jsonb)[-2];
jsonb
-------
"2"
(1 row)
select ('[1, "2", null]'::jsonb)[1]['a'];
jsonb
-------
(1 row)
select ('[1, "2", null]'::jsonb)[1][0];
jsonb
-------
(1 row)
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['b'];
jsonb
-------
"c"
(1 row)
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'];
jsonb
-----------
[1, 2, 3]
(1 row)
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'][1];
jsonb
-------
2
(1 row)
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d']['a'];
jsonb
-------
(1 row)
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1'];
jsonb
---------------
{"a2": "aaa"}
(1 row)
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2'];
jsonb
-------
"aaa"
(1 row)
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2']['a3'];
jsonb
-------
(1 row)
select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'];
jsonb
-----------------------
["aaa", "bbb", "ccc"]
(1 row)
select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'][2];
jsonb
-------
"ccc"
(1 row)
-- slices are not supported
select ('{"a": 1}'::jsonb)['a':'b'];
ERROR: jsonb subscript does not support slices
LINE 1: select ('{"a": 1}'::jsonb)['a':'b'];
^
select ('[1, "2", null]'::jsonb)[1:2];
ERROR: jsonb subscript does not support slices
LINE 1: select ('[1, "2", null]'::jsonb)[1:2];
^
select ('[1, "2", null]'::jsonb)[:2];
ERROR: jsonb subscript does not support slices
LINE 1: select ('[1, "2", null]'::jsonb)[:2];
^
select ('[1, "2", null]'::jsonb)[1:];
ERROR: jsonb subscript does not support slices
LINE 1: select ('[1, "2", null]'::jsonb)[1:];
^
select ('[1, "2", null]'::jsonb)[:];
ERROR: jsonb subscript does not support slices
create TEMP TABLE test_jsonb_subscript (
id int,
test_json jsonb
);
insert into test_jsonb_subscript values
(1, '{}'), -- empty jsonb
(2, '{"key": "value"}'); -- jsonb with data
-- update empty jsonb
update test_jsonb_subscript set test_json['a'] = '1' where id = 1;
select * from test_jsonb_subscript;
id | test_json
----+------------------
2 | {"key": "value"}
1 | {"a": 1}
(2 rows)
-- update jsonb with some data
update test_jsonb_subscript set test_json['a'] = '1' where id = 2;
select * from test_jsonb_subscript;
id | test_json
----+--------------------------
1 | {"a": 1}
2 | {"a": 1, "key": "value"}
(2 rows)
-- replace jsonb
update test_jsonb_subscript set test_json['a'] = '"test"';
select * from test_jsonb_subscript;
id | test_json
----+-------------------------------
1 | {"a": "test"}
2 | {"a": "test", "key": "value"}
(2 rows)
-- replace by object
update test_jsonb_subscript set test_json['a'] = '{"b": 1}'::jsonb;
select * from test_jsonb_subscript;
id | test_json
----+---------------------------------
1 | {"a": {"b": 1}}
2 | {"a": {"b": 1}, "key": "value"}
(2 rows)
-- replace by array
update test_jsonb_subscript set test_json['a'] = '[1, 2, 3]'::jsonb;
select * from test_jsonb_subscript;
id | test_json
----+----------------------------------
1 | {"a": [1, 2, 3]}
2 | {"a": [1, 2, 3], "key": "value"}
(2 rows)
-- use jsonb subscription in where clause
select * from test_jsonb_subscript where test_json['key'] = '"value"';
id | test_json
----+----------------------------------
2 | {"a": [1, 2, 3], "key": "value"}
(1 row)
select * from test_jsonb_subscript where test_json['key_doesnt_exists'] = '"value"';
id | test_json
----+-----------
(0 rows)
select * from test_jsonb_subscript where test_json['key'] = '"wrong_value"';
id | test_json
----+-----------
(0 rows)
-- NULL
update test_jsonb_subscript set test_json[NULL] = '1';
ERROR: jsonb subscript in assignment must not be null
update test_jsonb_subscript set test_json['another_key'] = NULL;
select * from test_jsonb_subscript;
id | test_json
----+-------------------------------------------------------
1 | {"a": [1, 2, 3], "another_key": null}
2 | {"a": [1, 2, 3], "key": "value", "another_key": null}
(2 rows)
-- NULL as jsonb source
insert into test_jsonb_subscript values (3, NULL);
update test_jsonb_subscript set test_json['a'] = '1' where id = 3;
select * from test_jsonb_subscript;
id | test_json
----+-------------------------------------------------------
1 | {"a": [1, 2, 3], "another_key": null}
2 | {"a": [1, 2, 3], "key": "value", "another_key": null}
3 | {"a": 1}
(3 rows)
update test_jsonb_subscript set test_json = NULL where id = 3;
update test_jsonb_subscript set test_json[0] = '1';
select * from test_jsonb_subscript;
id | test_json
----+---------------------------------------------------------------
1 | {"0": 1, "a": [1, 2, 3], "another_key": null}
2 | {"0": 1, "a": [1, 2, 3], "key": "value", "another_key": null}
3 | [1]
(3 rows)
-- jsonb to tsvector
select to_tsvector('{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
to_tsvector
......
......@@ -1177,7 +1177,7 @@ select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'retu
select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'delete_key') as delete_key;
select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'use_json_null') as use_json_null;
\pset null
\pset null ''
-- jsonb_insert
select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');
......@@ -1208,6 +1208,88 @@ select jsonb_insert('{"a": {"b": "value"}}', '{a, c}', '"new_value"', true);
select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"');
select jsonb_insert('{"a": {"b": "value"}}', '{a, b}', '"new_value"', true);
-- jsonb subscript
select ('123'::jsonb)['a'];
select ('123'::jsonb)[0];
select ('123'::jsonb)[NULL];
select ('{"a": 1}'::jsonb)['a'];
select ('{"a": 1}'::jsonb)[0];
select ('{"a": 1}'::jsonb)['not_exist'];
select ('{"a": 1}'::jsonb)[NULL];
select ('[1, "2", null]'::jsonb)['a'];
select ('[1, "2", null]'::jsonb)[0];
select ('[1, "2", null]'::jsonb)['1'];
select ('[1, "2", null]'::jsonb)[1.0];
select ('[1, "2", null]'::jsonb)[2];
select ('[1, "2", null]'::jsonb)[3];
select ('[1, "2", null]'::jsonb)[-2];
select ('[1, "2", null]'::jsonb)[1]['a'];
select ('[1, "2", null]'::jsonb)[1][0];
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['b'];
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'];
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d'][1];
select ('{"a": 1, "b": "c", "d": [1, 2, 3]}'::jsonb)['d']['a'];
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1'];
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2'];
select ('{"a": {"a1": {"a2": "aaa"}}, "b": "bbb", "c": "ccc"}'::jsonb)['a']['a1']['a2']['a3'];
select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'];
select ('{"a": ["a1", {"b1": ["aaa", "bbb", "ccc"]}], "b": "bb"}'::jsonb)['a'][1]['b1'][2];
-- slices are not supported
select ('{"a": 1}'::jsonb)['a':'b'];
select ('[1, "2", null]'::jsonb)[1:2];
select ('[1, "2", null]'::jsonb)[:2];
select ('[1, "2", null]'::jsonb)[1:];
select ('[1, "2", null]'::jsonb)[:];
create TEMP TABLE test_jsonb_subscript (
id int,
test_json jsonb
);
insert into test_jsonb_subscript values
(1, '{}'), -- empty jsonb
(2, '{"key": "value"}'); -- jsonb with data
-- update empty jsonb
update test_jsonb_subscript set test_json['a'] = '1' where id = 1;
select * from test_jsonb_subscript;
-- update jsonb with some data
update test_jsonb_subscript set test_json['a'] = '1' where id = 2;
select * from test_jsonb_subscript;
-- replace jsonb
update test_jsonb_subscript set test_json['a'] = '"test"';
select * from test_jsonb_subscript;
-- replace by object
update test_jsonb_subscript set test_json['a'] = '{"b": 1}'::jsonb;
select * from test_jsonb_subscript;
-- replace by array
update test_jsonb_subscript set test_json['a'] = '[1, 2, 3]'::jsonb;
select * from test_jsonb_subscript;
-- use jsonb subscription in where clause
select * from test_jsonb_subscript where test_json['key'] = '"value"';
select * from test_jsonb_subscript where test_json['key_doesnt_exists'] = '"value"';
select * from test_jsonb_subscript where test_json['key'] = '"wrong_value"';
-- NULL
update test_jsonb_subscript set test_json[NULL] = '1';
update test_jsonb_subscript set test_json['another_key'] = NULL;
select * from test_jsonb_subscript;
-- NULL as jsonb source
insert into test_jsonb_subscript values (3, NULL);
update test_jsonb_subscript set test_json['a'] = '1' where id = 3;
select * from test_jsonb_subscript;
update test_jsonb_subscript set test_json = NULL where id = 3;
update test_jsonb_subscript set test_json[0] = '1';
select * from test_jsonb_subscript;
-- jsonb to tsvector
select to_tsvector('{"a": "aaa bbb ddd ccc", "b": ["eee fff ggg"], "c": {"d": "hhh iii"}}'::jsonb);
......
......@@ -1198,6 +1198,7 @@ JsonbIterator
JsonbIteratorToken
JsonbPair
JsonbParseState
JsonbSubWorkspace
JsonbTypeCategory
JsonbValue
JunkFilter
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment