This section describes:
functions and operators for processing and creating JSON data
the SQL/JSON path language
the SQL/JSON query functions
To provide native support for JSON data types within the SQL environment, PostgreSQL implements the SQL/JSON data model. This model comprises sequences of items. Each item can hold SQL scalar values, with an additional SQL/JSON null value, and composite data structures that use JSON arrays and objects. The model is a formalization of the implied data model in the JSON specification RFC 7159.
SQL/JSON allows you to handle JSON data alongside regular SQL data, with transaction support, including:
Uploading JSON data into the database and storing it in regular SQL columns as character or binary strings.
Generating JSON objects and arrays from relational data.
Querying JSON data using SQL/JSON query functions and SQL/JSON path language expressions.
To learn more about the SQL/JSON standard, see [sqltr-19075-6]. For details on JSON types supported in PostgreSQL, see Section 8.14.
   Table 9.45 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.45. 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  
         | 
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.46.
   Section 8.14.4
   describes how these operators can be used to effectively search indexed
   jsonb data.
  
Table 9.46. 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? (This is useful only with SQL-standard JSON path expressions, not predicate check expressions, since those always return a value.) 
         | 
| 
         
        Returns the result of a JSON path predicate check for the
        specified JSON value.
        (This is useful only
        with predicate
        check expressions, not SQL-standard JSON path expressions,
        since it will return  
         | 
    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.47 shows the functions that are
   available for constructing json and jsonb values.
   Some functions in this table have a RETURNING clause,
   which specifies the data type returned.  It must be one of json,
   jsonb, bytea, a character string type (text,
   char, or varchar), or a type
   that can be cast to json.
   By default, the json type is returned.
  
Table 9.47. JSON Creation Functions
| Function Description Example(s) | 
|---|
| 
        
         
        Converts any SQL value to  
         
         | 
| 
        
         
        Converts an SQL array to a JSON array.  The behavior is the same
        as  
         | 
| 
        
          
          
         Constructs a JSON array from either a series of
          
          
          | 
| 
        
         
        Converts an 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  
         | 
| 
         
          
         Constructs a JSON object of all the key/value pairs given,
         or an empty object if none are given.
          
          | 
| 
        
         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  
         | 
| 
         
          
         Converts a given expression specified as  
          | 
| Converts a given SQL scalar value into a JSON scalar value. If the input is NULL, an SQL null is returned. If the input is number or a boolean value, a corresponding JSON number or boolean value is returned. For any other value, a JSON string is returned. 
         
         | 
| 
         
        Converts an SQL/JSON expression into a character or binary string. The
         
         | 
Table 9.48 details SQL/JSON facilities for testing JSON.
Table 9.48. SQL/JSON Testing Functions
   Table 9.49 shows the functions that
   are available for processing json and jsonb values.
  
Table 9.49. 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")
 | 
| 
        
         
        Function for testing  
         
         jsonb_populate_record_valid ----------------------------- f (1 row) 
         ERROR: value too long for type character(2) 
         jsonb_populate_record_valid ----------------------------- t (1 row) 
         a ---- aa (1 row) 
 | 
| 
        
         
        
         
        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.
        (This is useful only with SQL-standard JSON path expressions, not
        predicate check
        expressions, since those always return a value.)
        If the  
         | 
| 
        
         
        Returns the SQL boolean result of a JSON path predicate check
        for the specified JSON value.
        (This is useful only
        with predicate
        check expressions, not SQL-standard JSON path expressions,
        since it will either fail or return  
         | 
| 
        
         
        Returns all JSON items returned by the JSON path for the specified
        JSON value.
        For SQL-standard JSON path expressions it returns the JSON
        values selected from  
         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 parameters are the same as
        for  
         | 
| 
        
         
        Returns the first JSON item returned by the JSON path for the
        specified JSON value, or  
         | 
| 
        
         
        
         
        
         
        
         
        
         
        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
         
         
         
         | 
   SQL/JSON path expressions specify item(s) to be retrieved
   from a JSON value, similarly to XPath expressions used
   for access to XML content. In PostgreSQL,
   path expressions are implemented as the jsonpath
   data type and can use any elements described in
   Section 8.14.7.
  
   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.
   If there is no match, the result will be NULL,
   false, or an error, depending on the function.
   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. The first element of a path must always
   be $. 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 accessor operator acts on the
   result(s) of the previous evaluation step, producing zero, one, or more
   output items from each input item.
  
For example, suppose you have some JSON data from a GPS tracker that you would like to parse, such as:
SELECT '{
  "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
      }
    ]
  }
}' AS json \gset
   (The above example can be copied-and-pasted
   into psql to set things up for the following
   examples.  Then psql will
   expand :'json' into a suitably-quoted string
   constant containing the JSON value.)
  
   To retrieve the available track segments, you need to use the
   . accessor
   operator to descend through surrounding JSON objects, for example:
key
=>select jsonb_path_query(:'json', '$.track.segments');jsonb_path_query ------------------------------------------------------------------------------------------------------------------------------------------------------------------- [{"HR": 73, "location": [47.763, 13.4034], "start time": "2018-10-14 10:05:14"}, {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}]
   To retrieve the contents of an array, you typically use the
   [*] operator.
   The following example will return the location coordinates for all
   the available track segments:
=>select jsonb_path_query(:'json', '$.track.segments[*].location');jsonb_path_query ------------------- [47.763, 13.4034] [47.706, 13.2635]
   Here we started with the whole JSON input value ($),
   then the .track accessor selected the JSON object
   associated with the "track" object key, then
   the .segments accessor selected the JSON array
   associated with the "segments" key within that
   object, then the [*] accessor selected each element
   of that array (producing a series of items), then
   the .location accessor selected the JSON array
   associated with the "location" key within each of
   those objects.  In this example, each of those objects had
   a "location" key; but if any of them did not,
   the .location accessor would have simply produced no
   output for that input item.
  
   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:
=>select jsonb_path_query(:'json', '$.track.segments[0].location');jsonb_path_query ------------------- [47.763, 13.4034]
   The result of each path evaluation step can be processed
   by one or more of the jsonpath operators and methods
   listed in Section 9.16.2.3.
   Each method name must be preceded by a dot. For example,
   you can get the size of an array:
=>select jsonb_path_query(:'json', '$.track.segments.size()');jsonb_path_query ------------------ 2
   More examples of using jsonpath operators
   and methods within path expressions appear below in
   Section 9.16.2.3.
  
   A path can also contain
   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
   produce 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.51.  Within a
   filter expression, the @ variable denotes the value
   being considered (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 as follows:
=>select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@ > 130)');jsonb_path_query ------------------ 135
To get the start times of segments with such values, you have to filter out irrelevant segments before selecting the start times, so the filter expression is applied to the previous step, and the path used in the condition is different:
=>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR > 130)."start time"');jsonb_path_query ----------------------- "2018-10-14 10:39:21"
You can use several filter expressions in sequence, if required. The following example selects start times of all segments that contain locations with relevant coordinates and high heart rate values:
=>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time"');jsonb_path_query ----------------------- "2018-10-14 10:39:21"
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:
=>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130)');jsonb_path_query ------------------ 135
You can also nest filter expressions within each other. This example returns the size of the track if it contains any segments with high heart rate values, or an empty sequence otherwise:
=>select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size()');jsonb_path_query ------------------ 2
PostgreSQL's implementation of the SQL/JSON path language has the following deviations from the SQL/JSON standard.
     As an extension to the SQL standard,
     a PostgreSQL path expression can be a
     Boolean predicate, whereas the SQL standard allows predicates only within
     filters. While SQL-standard path expressions return the relevant
     element(s) of the queried JSON value, predicate check expressions
     return the single three-valued jsonb result of the
     predicate: true,
     false, or null.
     For example, we could write this SQL-standard filter expression:
=>select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR > 130)');jsonb_path_query --------------------------------------------------------------------------------- {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}
     The similar predicate check expression simply
     returns true, indicating that a match exists:
=>select jsonb_path_query(:'json', '$.track.segments[*].HR > 130');jsonb_path_query ------------------ true
       Predicate check expressions are required in the
       @@ operator (and the
       jsonb_path_match function), and should not be used
       with the @? operator (or the
       jsonb_path_exists function).
      
      There are minor differences in the interpretation of regular
      expression patterns used in like_regex filters, as
      described in Section 9.16.2.4.
     
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 is defined as 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 structural errors that cannot be fixed as described below are suppressed, producing no match.
strict — if a structural error occurs, an error is raised.
Lax mode facilitates matching of a JSON document and path expression when 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 the operation. Also, comparison operators automatically unwrap their operands in 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 when:
       The path expression contains type() or
       size() 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 lax mode:
=>select jsonb_path_query(:'json', 'lax $.track.segments.location');jsonb_path_query ------------------- [47.763, 13.4034] [47.706, 13.2635]
In strict mode, the specified path must exactly match the structure of the queried JSON document, so using this path expression will cause an error:
=>select jsonb_path_query(:'json', 'strict $.track.segments.location');ERROR: jsonpath member accessor can only be applied to an object
    To get the same result as in lax mode, you have to explicitly unwrap the
    segments array:
=>select jsonb_path_query(:'json', 'strict $.track.segments[*].location');jsonb_path_query ------------------- [47.763, 13.4034] [47.706, 13.2635]
    The unwrapping behavior of lax mode can lead to surprising results. For
    instance, the following query using the .** accessor
    selects every HR value twice:
=>select jsonb_path_query(:'json', 'lax $.**.HR');jsonb_path_query ------------------ 73 135 73 135
    This happens because the .** accessor selects both
    the segments array and each of its elements, while
    the .HR accessor automatically unwraps arrays when
    using lax mode. To avoid surprising results, we recommend using
    the .** accessor only in strict mode. The
    following query selects each HR value just once:
=>select jsonb_path_query(:'json', 'strict $.**.HR');jsonb_path_query ------------------ 73 135
    The unwrapping of arrays can also lead to unexpected results. Consider this
    example, which selects all the location arrays:
=>select jsonb_path_query(:'json', 'lax $.track.segments[*].location');jsonb_path_query ------------------- [47.763, 13.4034] [47.706, 13.2635] (2 rows)
As expected it returns the full arrays. But applying a filter expression causes the arrays to be unwrapped to evaluate each item, returning only the items that match the expression:
=>select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*] > 15)');jsonb_path_query ------------------ 47.763 47.706 (2 rows)
This despite the fact that the full arrays are selected by the path expression. Use strict mode to restore selecting the arrays:
=>select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*] > 15)');jsonb_path_query ------------------- [47.763, 13.4034] [47.706, 13.2635] (2 rows)
    Table 9.50 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.  In lax mode, methods applied to an array will be
    executed for each value in the array.  The exceptions are
    .type() and .size(), which apply to
    the array itself.
   
Table 9.50. 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) 
         | 
| 
         Boolean value converted from a JSON boolean, number, or string 
         | 
| 
         String value converted from a JSON boolean, number, string, or datetime 
         
         | 
| 
         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 
         | 
| 
         Big integer value converted from a JSON number or string 
         | 
| 
         
        Rounded decimal value converted from a JSON number or string
        ( 
         | 
| 
         Integer value converted from a JSON number or string 
         | 
| 
         Numeric value converted from a JSON number or string 
         | 
| 
         Date/time value converted from a string 
         | 
| 
         
        Date/time value converted from a string using the
        specified  
         | 
| 
         Date value converted from a string 
         | 
| 
         Time without time zone value converted from a string 
         | 
| 
         Time without time zone value converted from a string, with fractional seconds adjusted to the given precision 
         | 
| 
         Time with time zone value converted from a string 
         | 
| 
         Time with time zone value converted from a string, with fractional seconds adjusted to the given precision 
         | 
| 
         Timestamp without time zone value converted from a string 
         | 
| 
         Timestamp without time zone value converted from a string, with fractional seconds adjusted to the given precision 
         | 
| 
         Timestamp with time zone value converted from a string 
         | 
| 
         Timestamp with time zone value converted from a string, with fractional seconds adjusted to the given precision 
         | 
| 
         
        The object's key-value pairs, represented as an array of objects
        containing three fields:  
         | 
      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.  Similarly, other
      date/time-related methods that convert strings to date/time types
      also do this casting, which may involve the current
      TimeZone setting. Therefore, these conversions can
      also only be performed within timezone-aware jsonpath
      functions.
     
Table 9.51 shows the available filter expression elements.
Table 9.51. 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  
         
         | 
     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.7.  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+$")
   SQL/JSON functions JSON_EXISTS(),
   JSON_QUERY(), and JSON_VALUE()
   described in Table 9.52 can be used
   to query JSON documents.  Each of these functions apply a
   path_expression (an SQL/JSON path query) to a
   context_item (the document).  See
   Section 9.16.2 for more details on what
   the path_expression can contain. The
   path_expression can also reference variables,
   whose values are specified with their respective names in the
   PASSING clause that is supported by each function.
   context_item can be a jsonb value
   or a character string that can be successfully cast to jsonb.
  
Table 9.52. SQL/JSON Query Functions
| Function signature Description Example(s) | 
|---|
| 
 
 
 Examples: 
         
         
         ERROR: jsonpath array subscript is out of bounds 
 | 
| 
 
 
 Examples: 
         
         
         ERROR: malformed array literal: "[1, 2]" DETAIL: Missing "]" after array dimensions. 
 | 
| 
 
 
 Examples: 
         
         
         
         | 
    The context_item expression is converted to
    jsonb by an implicit cast if the expression is not already of
    type jsonb. Note, however, that any parsing errors that occur
    during that conversion are thrown unconditionally, that is, are not
    handled according to the (specified or implicit) ON ERROR
    clause.
   
    JSON_VALUE() returns an SQL NULL if
    path_expression returns a JSON
    null, whereas JSON_QUERY() returns
    the JSON null as is.
   
   JSON_TABLE is an SQL/JSON function which
   queries JSON data
   and presents the results as a relational view, which can be accessed as a
   regular SQL table. You can use JSON_TABLE inside
   the FROM clause of a SELECT,
   UPDATE, or DELETE and as data source
   in a MERGE statement.
  
   Taking JSON data as input, JSON_TABLE uses a JSON path
   expression to extract a part of the provided data to use as a
   row pattern for the constructed view.  Each SQL/JSON
   value given by the row pattern serves as source for a separate row in the
   constructed view.
  
   To split the row pattern into columns, JSON_TABLE
   provides the COLUMNS clause that defines the
   schema of the created view. For each column, a separate JSON path expression
   can be specified to be evaluated against the row pattern to get an SQL/JSON
   value that will become the value for the specified column in a given output
   row.
  
   JSON data stored at a nested level of the row pattern can be extracted using
   the NESTED PATH clause.  Each
   NESTED PATH clause can be used to generate one or more
   columns using the data from a nested level of the row pattern.  Those
   columns can be specified using a COLUMNS clause that
   looks similar to the top-level COLUMNS clause.  Rows constructed from
   NESTED COLUMNS are called child rows and are joined
   against the row constructed from the columns specified in the parent
   COLUMNS clause to get the row in the final view.  Child
   columns themselves may contain a NESTED PATH
   specification thus allowing to extract data located at arbitrary nesting
   levels.  Columns produced by multiple NESTED PATHs at the
   same level are considered to be siblings of each
   other and their rows after joining with the parent row are combined using
   UNION.
  
   The rows produced by JSON_TABLE are laterally
   joined to the row that generated them, so you do not have to explicitly join
   the constructed view with the original table holding JSON
   data.
  
The syntax is:
JSON_TABLE (
    context_item, path_expression [ AS json_path_name ] [ PASSING { value AS varname } [, ...] ]
    COLUMNS ( json_table_column [, ...] )
    [ { ERROR | EMPTY [ARRAY]} ON ERROR ]
)
where json_table_column is:
  name FOR ORDINALITY
  | name type
        [ FORMAT JSON [ENCODING UTF8]]
        [ PATH path_expression ]
        [ { WITHOUT | WITH { CONDITIONAL | [UNCONDITIONAL] } } [ ARRAY ] WRAPPER ]
        [ { KEEP | OMIT } QUOTES [ ON SCALAR STRING ] ]
        [ { ERROR | NULL | EMPTY { [ARRAY] | OBJECT } | DEFAULT expression } ON EMPTY ]
        [ { ERROR | NULL | EMPTY { [ARRAY] | OBJECT } | DEFAULT expression } ON ERROR ]
  | name type EXISTS [ PATH path_expression ]
        [ { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR ]
  | NESTED [ PATH ] path_expression [ AS json_path_name ] COLUMNS ( json_table_column [, ...] )
Each syntax element is described below in more detail.
context_item, path_expression [ AS json_path_name ] [ PASSING { value AS varname } [, ...]]
     The context_item specifies the input document
     to query, the path_expression is an SQL/JSON
     path expression defining the query, and json_path_name
     is an optional name for the path_expression.
     The optional PASSING clause provides data values for
     the variables mentioned in the path_expression.
     The result of the input data evaluation using the aforementioned elements
     is called the row pattern, which is used as the
     source for row values in the constructed view.
    
COLUMNS ( json_table_column [, ...] )
    
     The COLUMNS clause defining the schema of the
     constructed view. In this clause, you can specify each column to be
     filled with an SQL/JSON value obtained by applying a JSON path expression
     against the row pattern.  json_table_column has
     the following variants:
    
name FOR ORDINALITY
    
     Adds an ordinality column that provides sequential row numbering starting
     from 1.  Each NESTED PATH (see below) gets its own
     counter for any nested ordinality columns.
    
name type
          [FORMAT JSON [ENCODING UTF8]]
          [ PATH path_expression ]
     Inserts an SQL/JSON value obtained by applying
     path_expression against the row pattern into
     the view's output row after coercing it to specified
     type.
    
     Specifying FORMAT JSON makes it explicit that you
     expect the value to be a valid json object.  It only
     makes sense to specify FORMAT JSON if
     type is one of bpchar,
     bytea, character varying, name,
     json, jsonb, text, or a domain over
     these types.
    
     Optionally, you can specify WRAPPER and
     QUOTES clauses to format the output. Note that
     specifying OMIT QUOTES overrides
     FORMAT JSON if also specified, because unquoted
     literals do not constitute valid json values.
    
     Optionally, you can use ON EMPTY and
     ON ERROR clauses to specify whether to throw the error
     or return the specified value when the result of JSON path evaluation is
     empty and when an error occurs during JSON path evaluation or when
     coercing the SQL/JSON value to the specified type, respectively.  The
     default for both is to return a NULL value.
    
      This clause is internally turned into and has the same semantics as
      JSON_VALUE or JSON_QUERY.
      The latter if the specified type is not a scalar type or if either of
      FORMAT JSON, WRAPPER, or
      QUOTES clause is present.
     
name type
       EXISTS [ PATH path_expression ]
    
     Inserts a boolean value obtained by applying
     path_expression against the row pattern
     into the view's output row after coercing it to specified
     type.
    
     The value corresponds to whether applying the PATH
     expression to the row pattern yields any values.
    
     The specified type should have a cast from the
     boolean type.
    
     Optionally, you can use ON ERROR to specify whether to
     throw the error or return the specified value when an error occurs during
     JSON path evaluation or when coercing SQL/JSON value to the specified
     type.  The default is to return a boolean value
     FALSE.
    
      This clause is internally turned into and has the same semantics as
      JSON_EXISTS.
     
NESTED [ PATH ] path_expression [ AS json_path_name ]
          COLUMNS ( json_table_column [, ...] )
    
     Extracts SQL/JSON values from nested levels of the row pattern,
     generates one or more columns as defined by the COLUMNS
     subclause, and inserts the extracted SQL/JSON values into those
     columns.  The json_table_column
     expression in the COLUMNS subclause uses the same
     syntax as in the parent COLUMNS clause.
    
     The NESTED PATH syntax is recursive,
     so you can go down multiple nested levels by specifying several
     NESTED PATH subclauses within each other.
     It allows to unnest the hierarchy of JSON objects and arrays
     in a single function invocation rather than chaining several
     JSON_TABLE expressions in an SQL statement.
    
      In each variant of json_table_column described
      above, if the PATH clause is omitted, path expression
      $. is used, where
      namename is the provided column name.
     
AS json_path_name
    
     The optional json_path_name serves as an
     identifier of the provided path_expression.
     The name must be unique and distinct from the column names.
    
ERROR | EMPTY } ON ERROR
    
     The optional ON ERROR can be used to specify how to
     handle errors when evaluating the top-level
     path_expression.  Use ERROR
     if you want the errors to be thrown and EMPTY to
     return an empty table, that is, a table containing 0 rows.  Note that
     this clause does not affect the errors that occur when evaluating
     columns, for which the behavior depends on whether the
     ON ERROR clause is specified against a given column.
    
Examples
In the examples that follow, the following table containing JSON data will be used:
CREATE TABLE my_films ( js jsonb );
INSERT INTO my_films VALUES (
'{ "favorites" : [
   { "kind" : "comedy", "films" : [
     { "title" : "Bananas",
       "director" : "Woody Allen"},
     { "title" : "The Dinner Game",
       "director" : "Francis Veber" } ] },
   { "kind" : "horror", "films" : [
     { "title" : "Psycho",
       "director" : "Alfred Hitchcock" } ] },
   { "kind" : "thriller", "films" : [
     { "title" : "Vertigo",
       "director" : "Alfred Hitchcock" } ] },
   { "kind" : "drama", "films" : [
     { "title" : "Yojimbo",
       "director" : "Akira Kurosawa" } ] }
  ] }');
      The following query shows how to use JSON_TABLE to
      turn the JSON objects in the my_films table
      to a view containing columns for the keys kind,
      title, and director contained in
      the original JSON along with an ordinality column:
SELECT jt.* FROM my_films, JSON_TABLE (js, '$.favorites[*]' COLUMNS ( id FOR ORDINALITY, kind text PATH '$.kind', title text PATH '$.films[*].title' WITH WRAPPER, director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
id | kind | title | director ----+----------+--------------------------------+---------------------------------- 1 | comedy | ["Bananas", "The Dinner Game"] | ["Woody Allen", "Francis Veber"] 2 | horror | ["Psycho"] | ["Alfred Hitchcock"] 3 | thriller | ["Vertigo"] | ["Alfred Hitchcock"] 4 | drama | ["Yojimbo"] | ["Akira Kurosawa"] (4 rows)
      The following is a modified version of the above query to show the
      usage of PASSING arguments in the filter specified in
      the top-level JSON path expression and the various options for the
      individual columns:
SELECT jt.* FROM
 my_films,
 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
   PASSING 'Alfred Hitchcock' AS filter
     COLUMNS (
     id FOR ORDINALITY,
     kind text PATH '$.kind',
     title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
     director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
id | kind | title | director ----+----------+---------+-------------------- 1 | horror | Psycho | "Alfred Hitchcock" 2 | thriller | Vertigo | "Alfred Hitchcock" (2 rows)
      The following is a modified version of the above query to show the usage
      of NESTED PATH for populating title and director
      columns, illustrating how they are joined to the parent columns id and
      kind:
SELECT jt.* FROM
 my_films,
 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
   PASSING 'Alfred Hitchcock' AS filter
   COLUMNS (
    id FOR ORDINALITY,
    kind text PATH '$.kind',
    NESTED PATH '$.films[*]' COLUMNS (
      title text FORMAT JSON PATH '$.title' OMIT QUOTES,
      director text PATH '$.director' KEEP QUOTES))) AS jt;
id | kind | title | director ----+----------+---------+-------------------- 1 | horror | Psycho | "Alfred Hitchcock" 2 | thriller | Vertigo | "Alfred Hitchcock" (2 rows)
The following is the same query but without the filter in the root path:
SELECT jt.* FROM
 my_films,
 JSON_TABLE ( js, '$.favorites[*]'
   COLUMNS (
    id FOR ORDINALITY,
    kind text PATH '$.kind',
    NESTED PATH '$.films[*]' COLUMNS (
      title text FORMAT JSON PATH '$.title' OMIT QUOTES,
      director text PATH '$.director' KEEP QUOTES))) AS jt;
id | kind | title | director ----+----------+-----------------+-------------------- 1 | comedy | Bananas | "Woody Allen" 1 | comedy | The Dinner Game | "Francis Veber" 2 | horror | Psycho | "Alfred Hitchcock" 3 | thriller | Vertigo | "Alfred Hitchcock" 4 | drama | Yojimbo | "Akira Kurosawa" (5 rows)
      The following shows another query using a different JSON
      object as input.  It shows the UNION "sibling join" between
      NESTED paths $.movies[*] and
      $.books[*] and also the usage of
      FOR ORDINALITY column at NESTED
      levels (columns movie_id, book_id,
      and author_id):
SELECT * FROM JSON_TABLE (
'{"favorites":
    [{"movies":
      [{"name": "One", "director": "John Doe"},
       {"name": "Two", "director": "Don Joe"}],
     "books":
      [{"name": "Mystery", "authors": [{"name": "Brown Dan"}]},
       {"name": "Wonder", "authors": [{"name": "Jun Murakami"}, {"name":"Craig Doe"}]}]
}]}'::json, '$.favorites[*]'
COLUMNS (
  user_id FOR ORDINALITY,
  NESTED '$.movies[*]'
    COLUMNS (
    movie_id FOR ORDINALITY,
    mname text PATH '$.name',
    director text),
  NESTED '$.books[*]'
    COLUMNS (
      book_id FOR ORDINALITY,
      bname text PATH '$.name',
      NESTED '$.authors[*]'
        COLUMNS (
          author_id FOR ORDINALITY,
          author_name text PATH '$.name'))));
 user_id | movie_id | mname | director | book_id |  bname  | author_id | author_name
---------+----------+-------+----------+---------+---------+-----------+--------------
       1 |        1 | One   | John Doe |         |         |           |
       1 |        2 | Two   | Don Joe  |         |         |           |
       1 |          |       |          |       1 | Mystery |         1 | Brown Dan
       1 |          |       |          |       2 | Wonder  |         1 | Jun Murakami
       1 |          |       |          |       2 | Wonder  |         2 | Craig Doe
(5 rows)