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