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.
ROOT directive
Supported by ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ROOT directive allows for wrapping the JSON document in a root object.
Consider the following query
SELECT id, title
FROM book
ORDER BY id
FOR JSON AUTO, ROOT ('result')
create.select(BOOK.ID, BOOK.TITLE)
.from(BOOK)
.orderBy(BOOK.ID)
.forJSON().auto().root("result")
.fetch();
This query produces a document like this:
{
"result": [
{"id": 1, "title": "1984"},
{"id": 2, "title": "Animal Farm"},
{"id": 3, "title": "O Alquimista"},
{"id": 4, "title": "Brida"}
]
}
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).orderBy(BOOK.ID).forJSON().auto().root("result")
Translates to the following dialect specific expressions:
Aurora Postgres, CockroachDB, Postgres, YugabyteDB
SELECT json_strip_nulls(json_build_object('result', json_agg(json_strip_nulls(json_build_object('ID', ID)))))
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t
DB2
SELECT json_object(
KEY 'result' VALUE CAST(('[' || listagg(
json_object(
KEY 'ID' VALUE ID
ABSENT ON NULL
),
','
) || ']') AS varchar(32672)) FORMAT JSON
ABSENT ON NULL
)
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t
H2
SELECT json_object(
KEY 'result' VALUE json_arrayagg(json_object(
KEY 'ID' VALUE ID
ABSENT ON NULL
))
ABSENT ON NULL
)
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t
MariaDB
SET @t = @@group_concat_max_len;
SET @@group_concat_max_len = 4294967295;
SELECT json_object('result', json_merge_preserve(
'[]',
json_merge_preserve(
'[]',
concat(
'[',
group_concat(json_object('ID', ID) SEPARATOR ','),
']'
)
)
))
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t;
SET @@group_concat_max_len = @t;
MySQL
SET @t = @@group_concat_max_len;
SET @@group_concat_max_len = 4294967295;
SELECT json_object('result', json_merge_preserve(
'[]',
concat(
'[',
group_concat(json_object('ID', ID) SEPARATOR ','),
']'
)
))
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t;
SET @@group_concat_max_len = @t;
Oracle
SELECT json_object(
KEY 'result' VALUE json_arrayagg(json_object(
KEY 'ID' VALUE ID
ABSENT ON NULL
RETURNING clob
) FORMAT JSON RETURNING clob) FORMAT JSON
ABSENT ON NULL
RETURNING clob
)
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t
SQLServer
SELECT (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
FOR JSON AUTO, ROOT ('result')
)
Trino
SELECT CAST(map_from_entries(filter(
ARRAY[row(
'result',
CAST(cast(array_agg(CAST(map_from_entries(filter(
ARRAY[row(
'ID',
CAST(ID AS json)
)],
e -> e[2] IS NOT NULL
)) AS json)) AS json) AS json)
)],
e -> e[2] IS NOT NULL
)) AS json)
FROM (
SELECT BOOK.ID
FROM BOOK
ORDER BY BOOK.ID
) t
ASE, Access, Aurora MySQL, BigQuery, ClickHouse, Databricks, DuckDB, Exasol, Firebird, HSQLDB, Hana, Informix, MemSQL, Redshift, SQLDataWarehouse, SQLite, Snowflake, Spanner, Sybase, Teradata, 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!