New versions: Dev (3.15) | Latest (3.14)

JSON_VALUE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The JSON_VALUE function is used to extract content from JSON documents using a JSON path expression.

SELECT json_value(
  '{"a":[1,2,3]}', 
  '$.a[1]'
)
FROM dual
create.select(jsonValue(
          val(JSON.valueOf("{\"a\":[1,2,3]}")),
          "$.a[1]"
      )
      .fetch();

The result would look like this:

+------------+
| json_value |
+------------+
| 2          | 
+------------+

If the value does not matter, but you just want to check for a value's existence, use the JSON_EXISTS predicate.

Dialect support

This example using jOOQ:

jsonValue(val(JSON.json("[1,2]")), "$[*]")

Translates to the following dialect specific expressions:

-- DB2, MARIADB, ORACLE
json_value('[1,2]', '$[*]')

-- MYSQL
json_extract('[1,2]', '$[*]')

-- POSTGRES
jsonb_path_query_first(CAST('[1,2]' AS jsonb), '$[*]'::jsonpath)

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, INGRES, MEMSQL, 
-- REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, VERTICA
/* UNSUPPORTED */

(These are currently generated with jOOQ 3.15, see #10141)

The jOOQ Logo