Available in versions: Dev (3.21)
This documentation is for the unreleased development version of jOOQ. Click on the above version links to get this documentation for a supported version of jOOQ.
JSON_QUERY
Supported by ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The JSON_QUERY function is used to extract document (non-scalar) content from JSON documents using a JSON path expression.
SELECT json_query(
'{"a":[1,2,3]}',
'$.a'
)
FROM dual
create.select(jsonQuery(
val(JSON.valueOf("{\"a\":[1,2,3]}")),
"$.a"
)
.fetch();
The result would look like this:
+------------+ | json_query | +------------+ | [1,2,3] | +------------+
Dialect support
This example using jOOQ:
jsonQuery(val(json("[1,2]")), "$[*]")
Translates to the following dialect specific expressions:
BigQuery, Oracle, SQLServer
json_query('[1,2]', '$[*]')
ClickHouse
JSON_QUERY('[1,2]', '$[*]')
DB2
coalesce(
json_query('[1,2]', '$[*]'),
CASE
WHEN json_value('[1,2]', '$[*]' DEFAULT 'empty' ON EMPTY) IS NULL THEN 'null'
END
)
DuckDB
json_extract(JSON '[1,2]', '$[*]')
MariaDB
json_extract(json_extract('[1,2]', '$'), '$[*]')
MySQL
json_extract(cast('[1,2]' AS json), '$[*]')
Postgres
json_query(cast('[1,2]' AS json), '$[*]')
Spanner
json_query(JSON '[1,2]', '$[*]')
SQLite
(JSON('[1,2]')->'$[*]')
YugabyteDB
jsonb_path_query_first(
cast('[1,2]' AS jsonb),
cast('$[*]' as jsonpath)
)
ASE, Access, Aurora MySQL, Aurora Postgres, CockroachDB, Databricks, Exasol, Firebird, H2, HSQLDB, Hana, Informix, MemSQL, Redshift, SQLDataWarehouse, Snowflake, Sybase, Teradata, Trino, Vertica
/* UNSUPPORTED */
Generated with jOOQ 3.21. Support in older jOOQ versions may differ. Translate your own SQL on our website
Feedback
Do you have any feedback about this page? We'd love to hear it!