9.16. JSON Functions and Operators
This section describes:
- 
    functions and operators for processing and creating JSON data 
- 
    the SQL/JSON path language 
To learn more about the SQL/JSON standard, see [sqltr-19075-6] . For details on JSON types supported in PostgreSQL , see Section 8.14 .
9.16.1. Processing and Creating JSON Data
   
    Table 9.44
   
   shows the operators that
   are available for use with JSON data types (see
   
    Section 8.14
   
   ).
   In addition, the usual comparison operators shown in
   
    Table 9.1
   
   are available for
   
    jsonb
   
   , though not for
   
    json
   
   .  The comparison
   operators follow the ordering rules for B-tree operations outlined in
   
    Section 8.14.4
   
   .
   See also
   
    Section 9.21
   
   for the aggregate
   function
   
    json_agg
   
   which aggregates record
   values as JSON, the aggregate function
   
    json_object_agg
   
   which aggregates pairs of values
   into a JSON object, and their
   
    jsonb
   
   equivalents,
   
    jsonb_agg
   
   and
   
    jsonb_object_agg
   
   .
  
    
     Table 9.44. 
     
      json
     
     and
     
      jsonb
     
     Operators
    
   
| Operator Description Example(s) | 
|---|
| 
          
          
         Extracts
         
           
          
          | 
| 
          
          Extracts JSON object field with the given key. 
          | 
| 
          
          
         Extracts
         
           
          | 
| 
          
          
         Extracts JSON object field with the given key, as
          
          | 
| 
          
          Extracts JSON sub-object at the specified path, where path elements can be either field keys or array indexes. 
          | 
| 
          
          
         Extracts JSON sub-object at the specified path as
          
          | 
Note
The field/element/path extraction operators return NULL, rather than failing, if the JSON input does not have the right structure to match the request; for example if no such key or array element exists.
   Some further operators exist only for
   
    jsonb
   
   , as shown
   in
   
    Table 9.45
   
   .
   
    Section 8.14.4
   
   describes how these operators can be used to effectively search indexed
   
    jsonb
   
   data.
  
    
     Table 9.45. Additional
     
      jsonb
     
     Operators
    
   
| Operator Description Example(s) | 
|---|
| 
          Does the first JSON value contain the second? (See Section 8.14.3 for details about containment.) 
          | 
| 
          Is the first JSON value contained in the second? 
          | 
| 
          Does the text string exist as a top-level key or array element within the JSON value? 
          
          | 
| 
          Do any of the strings in the text array exist as top-level keys or array elements? 
          | 
| 
          Do all of the strings in the text array exist as top-level keys or array elements? 
          | 
| 
          
         Concatenates two
          
          
          
          
          To append an array to another array as a single entry, wrap it in an additional layer of array, for example: 
          | 
| 
          Deletes a key (and its value) from a JSON object, or matching string value(s) from a JSON array. 
          
          | 
| 
          Deletes all matching keys or array elements from the left operand. 
          | 
| 
          Deletes the array element with specified index (negative integers count from the end). Throws an error if JSON value is not an array. 
          | 
| 
          Deletes the field or array element at the specified path, where path elements can be either field keys or array indexes. 
          | 
| 
          Does JSON path return any item for the specified JSON value? 
          | 
| 
          
         Returns the result of a JSON path predicate check for the
        specified JSON value.  Only the first item of the result is taken into
        account.  If the result is not Boolean, then
          
          | 
Note
    The
    
     jsonpath
    
    operators
    
     @?
    
    and
    
     @@
    
    suppress the following errors: missing object
    field or array element, unexpected JSON item type, datetime and numeric
    errors.  The
    
     jsonpath
    
    -related functions described below can
    also be told to suppress these types of errors.  This behavior might be
    helpful when searching JSON document collections of varying structure.
   
   
    Table 9.46
   
   shows the functions that are
   available for constructing
   
    json
   
   and
   
    jsonb
   
   values.
  
Table 9.46. JSON Creation Functions
| Function Description Example(s) | 
|---|
| 
         
         
          
         Converts any SQL value to
          
          
          | 
| 
         
         
          
         Converts a SQL array to a JSON array.  The behavior is the same
        as
          
          | 
| 
         
         
          
         Converts a SQL composite value to a JSON object.  The behavior is the
        same as
          
          | 
| 
         
         
          
         
         
          
         Builds a possibly-heterogeneously-typed JSON array out of a variadic
        argument list.  Each argument is converted as
        per
          
          | 
| 
         
         
          
         
         
          
         Builds a JSON object out of a variadic argument list.  By convention,
        the argument list consists of alternating keys and values.  Key
        arguments are coerced to text; value arguments are converted as
        per
          
          | 
| 
         
         
          Builds a JSON object out of a text array. The array must have either exactly one dimension with an even number of members, in which case they are taken as alternating key/value pairs, or two dimensions such that each inner array has exactly two elements, which are taken as a key/value pair. All values are converted to JSON strings. 
          
          | 
| 
          
          
         This form of
          
          | 
   
    Table 9.47
   
   shows the functions that
   are available for processing
   
    json
   
   and
   
    jsonb
   
   values.
  
Table 9.47. JSON Processing Functions
| Function Description Example(s) | 
|---|
| 
         
         
          
         
         
          Expands the top-level JSON array into a set of JSON values. 
          value ----------- 1 true [2,false] 
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON array into a set of
          
          value ----------- foo bar 
 | 
| 
         
         
          
         
         
          Returns the number of elements in the top-level JSON array. 
          
          | 
| 
         
         
          
         
         
          Expands the top-level JSON object into a set of key/value pairs. 
          key | value -----+------- a | "foo" b | "bar" 
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON object into a set of key/value pairs.
        The returned
         
           
          key | value -----+------- a | foo b | bar 
 | 
| 
         
         
          
         
         
          
         Extracts JSON sub-object at the specified path.
        (This is functionally equivalent to the
          
          | 
| 
         
         
          
         
         
          
         Extracts JSON sub-object at the specified path as
          
          | 
| 
         
         
          
         
         
          Returns the set of keys in the top-level JSON object. 
          json_object_keys ------------------ f1 f2 
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON object to a row having the composite type
        of the
         
           To convert a JSON value to the SQL type of an output column, the following rules are applied in sequence: 
 
 
         While the example below uses a constant JSON value, typical use would
        be to reference a
          
          
          
 a |   b       |      c
---+-----------+-------------
 1 | {2,"a b"} | (4,"a b c")
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON array of objects to a set of rows having
        the composite type of the
         
           
          
          a | b ---+--- 1 | 2 3 | 4 
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON object to a row having the composite type
        defined by an
          
          
          
 a |    b    |    c    | d |       r
---+---------+---------+---+---------------
 1 | [1,2,3] | {1,2,3} |   | (123,"a b c")
 | 
| 
         
         
          
         
         
          
         Expands the top-level JSON array of objects to a set of rows having
        the composite type defined by an
          
          a | b ---+----- 1 | foo 2 | 
 | 
| 
         
         
          
         Returns
         
           
          
          | 
| 
         
         
          
         If
         
           
          
          | 
| 
         
         
          
         Returns
         
           
          
          | 
| 
         
         
          
         
         
          Deletes all object fields that have null values from the given JSON value, recursively. Null values that are not object fields are untouched. 
          | 
| 
         
         
          
         Checks whether the JSON path returns any item for the specified JSON
        value.
        If the
         
           
          | 
| 
         
         
          
         Returns the result of a JSON path predicate check for the specified
        JSON value.  Only the first item of the result is taken into account.
        If the result is not Boolean, then
          
          | 
| 
         
         
          
         Returns all JSON items returned by the JSON path for the specified
        JSON value.
        The optional
         
           
          jsonb_path_query ------------------ 2 3 4 
 | 
| 
         
         
          
         Returns all JSON items returned by the JSON path for the specified
        JSON value, as a JSON array.
        The optional
         
           
          | 
| 
         
         
          
         Returns the first JSON item returned by the JSON path for the
        specified JSON value.  Returns
          
          | 
| 
         
         
          
         
         
          
         
         
          
         
         
          
         
         
          
         These functions act like their counterparts described above without
        the
          
          | 
| Converts the given JSON value to pretty-printed, indented text. 
          
[
    {
        "f1": 1,
        "f2": null
    },
    2
]
 | 
| 
         Returns the type of the top-level JSON value as a text string.
        Possible types are
          
          
          
          | 
9.16.2. The SQL/JSON Path Language
   SQL/JSON path expressions specify the items to be retrieved
   from the JSON data, similar to XPath expressions used
   for SQL access to XML. In
   
    PostgreSQL
   
   ,
   path expressions are implemented as the
   
    jsonpath
   
   data type and can use any elements described in
   
    Section 8.14.6
   
   .
  
JSON query functions and operators pass the provided path expression to the path engine for evaluation. If the expression matches the queried JSON data, the corresponding JSON item, or set of items, is returned. Path expressions are written in the SQL/JSON path language and can include arithmetic expressions and functions.
   A path expression consists of a sequence of elements allowed
   by the
   
    jsonpath
   
   data type.
   The path expression is normally evaluated from left to right, but
   you can use parentheses to change the order of operations.
   If the evaluation is successful, a sequence of JSON items is produced,
   and the evaluation result is returned to the JSON query function
   that completes the specified computation.
  
   To refer to the JSON value being queried (the
   
    context item
   
   ), use the
   
    $
   
   variable
   in the path expression. It can be followed by one or more
   
    accessor operators
   
   ,
   which go down the JSON structure level by level to retrieve sub-items
   of the context item. Each operator that follows deals with the
   result of the previous evaluation step.
  
For example, suppose you have some JSON data from a GPS tracker that you would like to parse, such as:
{
  "track": {
    "segments": [
      {
        "location":   [ 47.763, 13.4034 ],
        "start time": "2018-10-14 10:05:14",
        "HR": 73
      },
      {
        "location":   [ 47.706, 13.2635 ],
        "start time": "2018-10-14 10:39:21",
        "HR": 135
      }
    ]
  }
}
  
   To retrieve the available track segments, you need to use the
   
    .
    
     
   accessor
   operator to descend through surrounding JSON objects:
  
      key
     
    
   
$.track.segments
   To retrieve the contents of an array, you typically use the
   
    [*]
   
   operator. For example,
   the following path will return the location coordinates for all
   the available track segments:
  
$.track.segments[*].location
   To return the coordinates of the first segment only, you can
   specify the corresponding subscript in the
   
    []
   
   accessor operator. Recall that JSON array indexes are 0-relative:
  
$.track.segments[0].location
   The result of each path evaluation step can be processed
   by one or more
   
    jsonpath
   
   operators and methods
   listed in
   
    Section 9.16.2.2
   
   .
   Each method name must be preceded by a dot. For example,
   you can get the size of an array:
  
$.track.segments.size()
   More examples of using
   
    jsonpath
   
   operators
   and methods within path expressions appear below in
   
    Section 9.16.2.2
   
   .
  
   When defining a path, you can also use one or more
   
    filter expressions
   
   that work similarly to the
   
    WHERE
   
   clause in SQL. A filter expression begins with
   a question mark and provides a condition in parentheses:
  
? (condition)
  
   Filter expressions must be written just after the path evaluation step
   to which they should apply. The result of that step is filtered to include
   only those items that satisfy the provided condition. SQL/JSON defines
   three-valued logic, so the condition can be
   
    true
   
   ,
   
    false
   
   ,
   or
   
    unknown
   
   . The
   
    unknown
   
   value
   plays the same role as SQL
   
    NULL
   
   and can be tested
   for with the
   
    is unknown
   
   predicate. Further path
   evaluation steps use only those items for which the filter expression
   returned
   
    true
   
   .
  
   The functions and operators that can be used in filter expressions are
   listed in
   
    Table 9.49
   
   .  Within a
   filter expression, the
   
    @
   
   variable denotes the value
   being filtered (i.e., one result of the preceding path step).  You can
   write accessor operators after
   
    @
   
   to retrieve component
   items.
  
For example, suppose you would like to retrieve all heart rate values higher than 130. You can achieve this using the following expression:
$.track.segments[*].HR ? (@ > 130)
To get the start times of segments with such values, you have to filter out irrelevant segments before returning the start times, so the filter expression is applied to the previous step, and the path used in the condition is different:
$.track.segments[*] ? (@.HR > 130)."start time"
You can use several filter expressions in sequence, if required. For example, the following expression selects start times of all segments that contain locations with relevant coordinates and high heart rate values:
$.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time"
Using filter expressions at different nesting levels is also allowed. The following example first filters all segments by location, and then returns high heart rate values for these segments, if available:
$.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130)
You can also nest filter expressions within each other:
$.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size()
This expression returns the size of the track if it contains any segments with high heart rate values, or an empty sequence otherwise.
PostgreSQL 's implementation of the SQL/JSON path language has the following deviations from the SQL/JSON standard:
- 
     A path expression can be a Boolean predicate, although the SQL/JSON standard allows predicates only in filters. This is necessary for implementation of the @@operator. For example, the followingjsonpathexpression is valid in PostgreSQL :$.track.segments[*].HR < 70 
- 
     There are minor differences in the interpretation of regular expression patterns used in like_regexfilters, as described in Section 9.16.2.3 .
9.16.2.1. Strict and Lax Modes
When you query JSON data, the path expression may not match the actual JSON data structure. An attempt to access a non-existent member of an object or element of an array results in a structural error. SQL/JSON path expressions have two modes of handling structural errors:
- 
      lax (default) - the path engine implicitly adapts the queried data to the specified path. Any remaining structural errors are suppressed and converted to empty SQL/JSON sequences. 
- 
      strict - if a structural error occurs, an error is raised. 
The lax mode facilitates matching of a JSON document structure and path expression if the JSON data does not conform to the expected schema. If an operand does not match the requirements of a particular operation, it can be automatically wrapped as an SQL/JSON array or unwrapped by converting its elements into an SQL/JSON sequence before performing this operation. Besides, comparison operators automatically unwrap their operands in the lax mode, so you can compare SQL/JSON arrays out-of-the-box. An array of size 1 is considered equal to its sole element. Automatic unwrapping is not performed only when:
- 
      The path expression contains type()orsize()methods that return the type and the number of elements in the array, respectively.
- 
      The queried JSON data contain nested arrays. In this case, only the outermost array is unwrapped, while all the inner arrays remain unchanged. Thus, implicit unwrapping can only go one level down within each path evaluation step. 
For example, when querying the GPS data listed above, you can abstract from the fact that it stores an array of segments when using the lax mode:
lax $.track.segments.location
    In the strict mode, the specified path must exactly match the structure of
    the queried JSON document to return an SQL/JSON item, so using this
    path expression will cause an error. To get the same result as in
    the lax mode, you have to explicitly unwrap the
    
     segments
    
    array:
   
strict $.track.segments[*].location
    The
    
     .**
    
    accessor can lead to surprising results
    when using the lax mode. For instance, the following query selects every
    
     HR
    
    value twice:
   
lax $.**.HR
    This happens because the
    
     .**
    
    accessor selects both
    the
    
     segments
    
    array and each of its elements, while
    the
    
     .HR
    
    accessor automatically unwraps arrays when
    using the lax mode. To avoid surprising results, we recommend using
    the
    
     .**
    
    accessor only in the strict mode. The
    following query selects each
    
     HR
    
    value just once:
   
strict $.**.HR
9.16.2.2. SQL/JSON Path Operators and Methods
    
     Table 9.48
    
    shows the operators and
    methods available in
    
     jsonpath
    
    .  Note that while the unary
    operators and methods can be applied to multiple values resulting from a
    preceding path step, the binary operators (addition etc.) can only be
    applied to single values.
   
     
      Table 9.48. 
      
       jsonpath
      
      Operators and Methods
     
    
| Operator/Method Description Example(s) | 
|---|
| 
          
            Addition 
           | 
| 
           Unary plus (no operation); unlike addition, this can iterate over multiple values 
           | 
| 
          
            Subtraction 
           | 
| 
           Negation; unlike subtraction, this can iterate over multiple values 
           | 
| 
          
            Multiplication 
           | 
| 
          
            Division 
           | 
| 
          
            Modulo (remainder) 
           | 
| 
          
            
          Type of the JSON item (see
           
           | 
| 
          
            Size of the JSON item (number of array elements, or 1 if not an array) 
           | 
| 
          
            Approximate floating-point number converted from a JSON number or string 
           | 
| 
          
            Nearest integer greater than or equal to the given number 
           | 
| 
          
            Nearest integer less than or equal to the given number 
           | 
| 
          
            Absolute value of the given number 
           | 
| 
          
            Date/time value converted from a string 
           | 
| 
          
            
          Date/time value converted from a string using the
        specified
           
           | 
| 
          
            
          The object's key-value pairs, represented as an array of objects
        containing three fields:
           
           | 
Note
     The result type of the
     
      datetime()
     
     and
     
      datetime(
      
       
     methods can be
     
        template
       
      
      )
     
      date
     
     ,
     
      timetz
     
     ,
     
      time
     
     ,
     
      timestamptz
     
     , or
     
      timestamp
     
     .
      Both methods determine their result type dynamically.
    
     The
     
      datetime()
     
     method sequentially tries to
      match its input string to the ISO formats
      for
     
      date
     
     ,
     
      timetz
     
     ,
     
      time
     
     ,
     
      timestamptz
     
     , and
     
      timestamp
     
     . It stops on
      the first matching format and emits the corresponding data type.
    
     The
     
      datetime(
      
       
     method determines the result type according to the fields used in the
      provided template string.
    
        template
       
      
      )
     
     The
     
      datetime()
     
     and
     
      datetime(
      
       
     methods
      use the same parsing rules as the
     
        template
       
      
      )
     
      to_timestamp
     
     SQL
      function does (see
     
      Section 9.8
     
     ), with three
      exceptions.  First, these methods don't allow unmatched template
      patterns.  Second, only the following separators are allowed in the
      template string: minus sign, period, solidus (slash), comma, apostrophe,
      semicolon, colon and space.  Third, separators in the template string
      must exactly match the input string.
    
     If different date/time types need to be compared, an implicit cast is
      applied. A
     
      date
     
     value can be cast to
     
      timestamp
     
     or
     
      timestamptz
     
     ,
     
      timestamp
     
     can be cast to
     
      timestamptz
     
     , and
     
      time
     
     to
     
      timetz
     
     .
      However, all but the first of these conversions depend on the current
     
      TimeZone
     
     setting, and thus can only be performed
      within timezone-aware
     
      jsonpath
     
     functions.
    
Table 9.49 shows the available filter expression elements.
     
      Table 9.49. 
      
       jsonpath
      
      Filter Expression Elements
     
    
| Predicate/Value Description Example(s) | 
|---|
| 
          
            Equality comparison (this, and the other comparison operators, work on all JSON scalar values) 
           
           | 
| 
          
            
          
            Non-equality comparison 
           
           | 
| 
          
            Less-than comparison 
           | 
| 
          
            Less-than-or-equal-to comparison 
           | 
| 
          
            Greater-than comparison 
           | 
| 
          
            Greater-than-or-equal-to comparison 
           | 
| 
           
          JSON constant
           
           | 
| 
           
          JSON constant
           
           | 
| 
           
          JSON constant
           
           | 
| 
          
            Boolean AND 
           | 
| 
          
            Boolean OR 
           | 
| 
           Boolean NOT 
           | 
| 
          
            
          Tests whether a Boolean condition is
           
           | 
| 
          
            
          Tests whether the first operand matches the regular expression
        given by the second operand, optionally with modifications
        described by a string of
           
           
           | 
| 
          
            Tests whether the second operand is an initial substring of the first operand. 
           | 
| 
           
          Tests whether a path expression matches at least one SQL/JSON item.
        Returns
           
           
           | 
9.16.2.3. SQL/JSON Regular Expressions
    SQL/JSON path expressions allow matching text to a regular expression
     with the
    
     like_regex
    
    filter.  For example, the
     following SQL/JSON path query would case-insensitively match all
     strings in an array that start with an English vowel:
   
$[*] ? (@ like_regex "^[aeiou]" flag "i")
    The optional
    
     flag
    
    string may include one or more of
     the characters
    
     i
    
    for case-insensitive match,
    
     m
    
    to allow
    
     ^
    
    and
    
     $
    
    to match at newlines,
    
     s
    
    to allow
    
     .
    
    to match a newline,
     and
    
     q
    
    to quote the whole pattern (reducing the
     behavior to a simple substring match).
   
    The SQL/JSON standard borrows its definition for regular expressions
     from the
    
     LIKE_REGEX
    
    operator, which in turn uses the
     XQuery standard.  PostgreSQL does not currently support the
    
     LIKE_REGEX
    
    operator.  Therefore,
     the
    
     like_regex
    
    filter is implemented using the
     POSIX regular expression engine described in
    
     Section 9.7.3
    
    .  This leads to various minor
     discrepancies from standard SQL/JSON behavior, which are cataloged in
    
     Section 9.7.3.8
    
    .
     Note, however, that the flag-letter incompatibilities described there
     do not apply to SQL/JSON, as it translates the XQuery flag letters to
     match what the POSIX engine expects.
   
    Keep in mind that the pattern argument of
    
     like_regex
    
    is a JSON path string literal, written according to the rules given in
    
     Section 8.14.6
    
    .  This means in particular that any
     backslashes you want to use in the regular expression must be doubled.
     For example, to match string values of the root document that contain
     only digits:
   
$.* ? (@ like_regex "^\\d+$")