12 SQL/JSON Path Expressions
Oracle Database provides SQL access to JSON data using SQL/JSON path expressions.
Topics:
- Overview of SQL/JSON Path Expressions
Oracle Database provides SQL access to JSON data using SQL/JSON path expressions. - SQL/JSON Path Expression Syntax
SQL/JSON path expressions are matched by SQL/JSON functions and conditions against JSON data, to select portions of it. Path expressions can use wildcards and array ranges. Matching is case-sensitive.
12.1 Overview of SQL/JSON Path Expressions
Oracle Database provides SQL access to JSON data using SQL/JSON path expressions.
JSON is a notation for JavaScript values. When JSON data is stored in the database you can query it using path expressions that are somewhat analogous to XQuery or XPath expressions for XML data. Similar to the way that SQL/XML allows SQL access to XML data using XQuery expressions, Oracle Database provides SQL access to JSON data using SQL/JSON path expressions.
SQL/JSON path expressions have a simple syntax. A path expression selects zero or more JSON values that match, or satisfy, it.
SQL/JSON condition json_exists
returns true if at least one value matches, and false if no value matches. If a single value matches, then SQL/JSON function json_value
returns that value if it is scalar and raises an error if it is non-scalar. If no value matches the path expression then json_value
returns SQL NULL
.
SQL/JSON function json_query
returns all of the matching values, that is, it can return multiple values. You can think of this behavior as returning a sequence of values, as in XQuery, or you can think of it as returning multiple values. (No user-visible sequence is manifested.)
In all cases, path-expression matching attempts to match each step of the path expression, in turn. If matching any step fails then no attempt is made to match the subsequent steps, and matching of the path expression fails. If matching each step succeeds then matching of the path expression succeeds.
Related Topics
12.2 SQL/JSON Path Expression Syntax
SQL/JSON path expressions are matched by SQL/JSON functions and conditions against JSON data, to select portions of it. Path expressions can use wildcards and array ranges. Matching is case-sensitive.
You pass a SQL/JSON path expression and some JSON data to a SQL/JSON function or condition. The path expression is matched against the data, and the matching data is processed by the particular SQL/JSON function or condition. You can think of this matching process in terms of the path expression returning the matched data to the function or condition.
Topics:
- Basic SQL/JSON Path Expression Syntax
The basic syntax of a SQL/JSON path expression is presented. It is composed of a context item followed by zero or more object or array steps, depending on the nature of the context item, followed optionally by a function step. Examples are provided. - SQL/JSON Path Expression Syntax Relaxation
The basic SQL/JSON path-expression syntax is relaxed to allow implicit array wrapping and unwrapping. This means that you need not change a path expression in your code if your data evolves to replace a JSON value with an array of such values, or vice versa. Examples are provided.
12.2.1 Basic SQL/JSON Path Expression Syntax
The basic syntax of a SQL/JSON path expression is presented. It is composed of a context item followed by zero or more object or array steps, depending on the nature of the context item, followed optionally by a function step. Examples are provided.
However, this basic syntax is extended by relaxing the matching of arrays and non-arrays against non-array and array patterns, respectively — see SQL/JSON Path Expression Syntax Relaxation.
Matching of data against SQL/JSON path expressions is case-sensitive.
-
A SQL/JSON basic path expression (also called just a path expression here) is an absolute simple path expression, followed by an optional filter expression.
The optional filter expression can be present only when the path expression is used in SQL condition
json_exists
. No steps can follow the filter expression. (This is not allowed, for example:$.a?(@.b == 2).c
.) -
An absolute simple path expression begins with a dollar sign (
$
), which represents the path-expression context item, that is, the JSON data to be matched. That data is the result of evaluating a SQL expression that is passed as argument to the SQL/JSON function.The dollar sign is followed by zero or more path steps. Each step can be an object step or an array step, depending on whether the context item represents a JSON object or a JSON array. The last step of a simple path expression can be a single, optional function step.
-
An object step is a period (
.
), sometimes read as "dot", followed by an object field name (object property name) or an asterisk (*
) wildcard, which stands for (the values of) all fields. A field name can be empty, in which case it must be written as""
. A nonempty field name must start with an uppercase or lowercase letter A to Z and contain only such letters or decimal digits (0-9), or else it must be enclosed in double quotation marks ("
). An object step returns the value of the field that is specified. If a wildcard is used for the field then the step returns the values of all fields, in no special order. -
An array step is a left bracket (
[
) followed by either an asterisk (*
) wildcard, which stands for all array elements, or one or more specific array indexes or range specifications separated by commas, followed by a right bracket (]
). In a path expression, array indexing is zero-based (0, 1, 2,...), as in the JavaScript convention for arrays. A range specification has the formN
toM
, whereN
andM
are array indexes andN
is strictly less thanM
. (An error is raised at query compilation time ifN
is not less thanM
.) An error is raised if you use both an asterisk and either an array index or range specification.When indexes or range specifications are used, the array elements they collectively specify must be specified in ascending order, without repetitions, or else a compile-time error is raised. For example, an error is raised for each of
[3, 1 to 4]
,[4, 2]
,[2, 3 to 3]
, and[2, 3, 3]
. Errors are raised on the first two because the order is not ascending, Errors are raised on the last two because of the repetition of element number3
(the fourth element, because of zero-based indexing).Similarly, the elements in the array value that results from matching are in ascending order, with no repetitions. If an asterisk is used in the path expression then all of the array elements are returned, in array order.
-
A single function step is optional. If present, it is the last step of the path expression. It is a dot (
.
), followed by a SQL/JSON item method. It is followed by a left parenthesis ((
) and then a right parenthesis ()
). The parentheses can have whitespace between them (such whitespace is insignificant). The function is applied to the data that is targeted by the rest of the same path expression, which precedes it. It is used to transform that data. The function or condition that is passed the path expression uses the transformed data in place of the targeted data.Note:
-
If an item method is applied to an array, it is in effect applied to each of the array elements. For example,
$.a.fun()
applies item-methodfun()
to each element of arraya
, to convert it. The resulting array of converted values is then used for matching, in place ofa
. -
If an item-method conversion fails for any reason, such as its argument being of the wrong type, then the path cannot be matched (it refers to no data), and no error is raised. In particular, this means that such an error is not handled by an error clause in the SQL/JSON function or condition to which the path expression is passed.
The available item methods are the following.
-
abs()
: The absolute value of the targeted JSON number. Corresponds to the use of SQL functionABS
. -
ceiling()
: The targeted JSON number, rounded up to the nearest integer. Corresponds to the use of SQL functionCEIL
. -
date()
: The SQLDATE
value that corresponds to the targeted JSON string. The string data must be in one of the ISO date formats. -
double()
: The SQLBINARY_DOUBLE
numeric value that corresponds to the targeted JSON string or number. -
floor()
: The targeted JSON number, rounded down to the nearest integer. Corresponds to the use of SQL functionFLOOR
. -
length()
: The number of characters in the targeted JSON string, as a SQLNUMBER
. -
lower()
: The lowercase string that corresponds to the characters in the targeted JSON string. -
number()
: The SQLNUMBER
value that corresponds to the targeted JSON string or number. -
string()
: A string representation of the targeted JSON value. The representation is the same as that used for theRETURNING
clause of a SQL/JSON function with return typeVARCHAR2
. (A Boolean value is represented by the string"true"
or"false"
; anull
value is represented by the string"null"
; and a number is represented in a canonical form.) Any error that occurs during serialization to the string representation is ignored. -
timestamp()
: The SQLTIMESTAMP
value that corresponds to the targeted JSON string. The string data must be in one of the ISO date formats. -
upper()
: The uppercase string that corresponds to the characters in the targeted JSON string.
Item methods
date()
,length()
,lower()
,number()
,string()
,timestamp(
), andupper()
are Oracle extensions to the SQL/JSON standard. The other item methods are part of the standard. -
-
A filter expression (filter, for short) is a question mark (
?
) followed by a filter condition enclosed in parentheses (()
). A filter is satisfied if its condition is satisfied, that is, returns true. -
A filter condition applies a predicate (Boolean function) to its arguments and is one of the following, where each of
cond
,cond1
, andcond2
stands for a filter condition.-
( cond )
: Parentheses are used for grouping, separating filter conditioncond
as a unit from other filter conditions that may precede or follow it. -
cond1 && cond2
: The conjunction (and) ofcond1
andcond2
, requiring that both be satisfied. -
cond1 || cond2
: The inclusive disjunction (or) ofcond1
andcond2
, requiring thatcond1
,cond2
, or both, be satisfied. -
! ( cond )
: The negation ofcond
, meaning thatcond
must not be satisfied. -
exists (
, followed by a relative simple path expression, followed by)
: The targeted data exists. -
A comparison, which is one of the following:
-
A relative simple path expression, followed by a comparison predicate, followed by either a JSON scalar value or a SQL/JSON variable.
-
Either a JSON scalar value or a SQL/JSON variable, followed by a comparison predicate, followed by a relative simple path expression.
-
A JSON scalar value, followed by a comparison predicate, followed by another JSON scalar value.
A comparison predicate is
==
,!=
,<
,<=
,>=
, or>
.A SQL/JSON variable is a dollar sign (
$
) followed by the name of a SQL identifier that is bound in aPASSING
clause forjson_exists
. -
The predicates that you can use in filter conditions are thus
&&
,||
,!
,exists
,==
,!=
,<
,<=
,>=
, and>
.As an example, the filter condition
(a || b) && (!(c) || d < 42)
is satisfied if both of the following criteria are met:-
At least one of the filter conditions
a
andb
is satisfied:(a || b)
. -
Filter condition
c
is not satisfied or the numberd
is less than or equal to 42, or both are true:(!(c) || d < 42)
.
Comparison predicate
!
has precedence over&&
, which has precedence over||
. You can always use parentheses to control grouping.Without parentheses for grouping, the preceding example would be
a || b && !(c) || d < 42
, which would be satisfied if at least one of the following criteria is met:-
Condition
b && !(c)
is satisfied, which means that each of the conditionsb
and!(c)
is satisfied (which in turn means that conditionc
is not satisfied). -
Condition
a
is satisfied. -
Condition
d < 42
is satisfied.
-
-
A relative simple path expression is an at sign (
@
) followed by zero or more path steps. The at sign represents the path-expression current filter item, that is, the JSON data that matches the part of the (surrounding) path expression that precedes the filter. The simple path expression is matched against the current filter item in the same way that a path expression is matched against the context item. -
A simple path expression is either an absolute simple path expression or a relative simple path expression. (The former begins with
$
; the latter begins with@
.)
Here are some examples of path expressions, with their meanings spelled out in detail.
-
$
– The context item. -
$.friends
– The value of fieldfriends
of a context-item object. The dot (.
) immediately after the dollar sign ($
) indicates that the context item is a JSON object. -
$.friends[0]
– An object that is the first element of an array that is the value of fieldfriends
of a context-item object. The bracket notation indicates that the value of fieldfriends
is an array. -
$.friends[0].name
– Value of fieldname
of an object that is the first element of an array that is the value of fieldfriends
of a context-item object. The second dot (.
) indicates that the first element of arrayfriends
is an object (with aname
field). -
$.friends[*].name
– Value of fieldname
of each object in an array that is the value of fieldfriends
of a context-item object. -
$.*[*].name
– Fieldname
values for each object in an array value of a field of a context-item object. -
$.friends[3, 8 to 10, 12]
– The fourth, ninth through eleventh, and thirteenth elements of an arrayfriends
(field of a context-item object). The elements must be specified in ascending order, and they are returned in that order: fourth, ninth, tenth, eleventh, thirteenth. -
$.friends[3].cars
– The value of fieldcars
of an object that is the fourth element of an arrayfriends
. The dot (.
) indicates that the fourth element is an object (with acars
field). -
$.friends[3].*
– The values of all of the fields of an object that is the fourth element of an arrayfriends
. -
$.friends[3].cars[0].year
– The value of fieldyear
of an object that is the first element of an array that is the value of fieldcars
of an object that is the fourth element of an arrayfriends
. -
$.friends[3].cars[0]?(@.year > 2014)
– The first object of an arraycars
(field of an object that is the fourth element of an arrayfriends
), provided that the value of its fieldyear
is greater than 2014. -
$.friends[3]?(@.addresses.city == "San Francisco")
– An object that is the fourth element of an arrayfriends
, provided that it has anaddresses
field whose value is an object with a fieldcity
whose value is the string"San Francisco"
. -
$.friends[3]?(@.addresses.city == "San Francisco" && @.addresses.state == "Nevada")
– Objects that are the fourth element of an arrayfriends
, provided that there is a match for an address with acity
of"San Francisco"
and there is a match for an address with astate
of"Nevada"
.Note: The filter conditions in the conjunction do not necessarily apply to the same object — the filter tests for the existence of an object with city San Francisco and for the existence of an object with state Nevada. It does not test for the existence of an object with both city San Francisco and state Nevada. See Using Filters with JSON_EXISTS.
-
$.friends[3].addresses?(@.city == "San Francisco" && @.state == "Nevada")
– An object that is the fourth element of arrayfriends
, provided that object has a match forcity
of"San Francisco"
and a match forstate
of"Nevada"
.Unlike the preceding example, in this case the filter conditions in the conjunction, for fields
city
andstate
, apply to the sameaddresses
object. The filter applies to a givenaddresses
object, which is outside it.
Related Topics
See Also:
ISO 8601 for information about the ISO date formats
12.2.2 SQL/JSON Path Expression Syntax Relaxation
The basic SQL/JSON path-expression syntax is relaxed to allow implicit array wrapping and unwrapping. This means that you need not change a path expression in your code if your data evolves to replace a JSON value with an array of such values, or vice versa. Examples are provided.
Basic SQL/JSON Path Expression Syntax defines the basic SQL/JSON path-expression syntax. The actual path expression syntax supported relaxes that definition as follows:
-
If a path-expression step targets (expects) an array but the actual data presents no array then the data is implicitly wrapped in an array.
-
If a path-expression step targets (expects) a non-array but the actual data presents an array then the array is implicitly unwrapped.
This relaxation allows for the following abbreviation: [*]
can be elided whenever it precedes the object accessor, .
, followed by an object field name, with no change in effect. The reverse is also true: [*]
can always be inserted in front of the object accessor, .
, with no change in effect.
This means that the object step [*].
prop
, which stands for the value of field prop
of each element of a given array of objects, can be abbreviated as .prop
, and the object step .prop
, which looks as though it stands for the prop
value of a single object, stands also for the prop
value of each element of an array to which the object accessor is applied.
This is an important feature, because it means that you need not change a path expression in your code if your data evolves to replace a given JSON value with an array of such values, or vice versa.
For example, if your data originally contains objects that have field Phone
whose value is a single object with fields type
and number
, the path expression $.Phone.number
, which matches a single phone number, can still be used if the data evolves to represent an array of phones. Path expression $.Phone.number
matches either a single phone object, selecting its number, or an array of phone objects, selecting the number of each.
Similarly, if your data mixes both kinds of representation — there are some data entries that use a single phone object and some that use an array of phone objects, or even some entries that use both — you can use the same path expression to access the phone information from these different kinds of entry.
Here are some example path expressions from section Basic SQL/JSON Path Expression Syntax, together with an explanation of equivalences.
-
$.friends
– The value of fieldfriends
of either:-
The (single) context-item object.
-
(equivalent to
$[*].friends
) Each object in the context-item array.
-
-
$.friends[0].name
– Value of fieldname
for any of these objects:-
The first element of the array that is the value of field
friends
of the context-item object. -
(equivalent to
$.friends.name
) The value of fieldfriends
of the context-item object. -
(equivalent to
$[*].friends.name
) The value of fieldfriends
of each object in the context-item array. -
(equivalent to
$[*].friends[0].name
) The first element of each array that is the value of fieldfriends
of each object in the context-item array.
The context item can be an object or an array of objects. In the latter case, each object in the array is matched for a field
friends
.The value of field
friends
can be an object or an array of objects. In the latter case, the first object in the array is used. -
-
$.*[*].name
– Value of fieldname
for any of these objects:-
An element of an array value of a field of the context-item object.
-
(equivalent to
$.*.name
) The value of a field of the context-item object. -
(equivalent to
$[*].*.name
) The value of a field of an object in the context-item array. -
(equivalent to
$[*].*[*].name
) Each object in an array value of a field of an object in the context-item array.
-
Related Topics