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_ARRAY from query

Supported by ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The JSON_ARRAY function is used to produce simple JSON arrays from the result of a single column query.

SELECT json_array(SELECT id FROM author)
 
create.select(jsonArray(select(AUTHOR.ID).from(AUTHOR)))
      .fetch();

The result would look like this:

+------------+
| json_array |
+------------+
| [1,2,3,4]  |
+------------+

Dialect support

This example using jOOQ:

jsonArray(select(AUTHOR.ID).from(AUTHOR))

Translates to the following dialect specific expressions:

Aurora Postgres, Postgres

coalesce(
  json_array(
    SELECT AUTHOR.ID
    FROM AUTHOR
    RETURNING json
  ),
  CAST('[]' AS json)
)

BigQuery, ClickHouse, DB2, H2, Oracle, Snowflake

json_array(
  SELECT AUTHOR.ID
  FROM AUTHOR
)

CockroachDB

coalesce(
  (
    SELECT json_agg(a)
    FROM (
      SELECT AUTHOR.ID
      FROM AUTHOR
    ) t (a)
  ),
  CAST('[]' AS json)
)

DuckDB

coalesce(
  (
    SELECT to_json(array_agg(a))
    FROM (
      SELECT AUTHOR.ID
      FROM AUTHOR
    ) t (a)
  ),
  JSON '[]'
)

MariaDB

ifnull(
  (
    SELECT json_merge_preserve(
      '[]',
      concat(
        '[',
        group_concat(a SEPARATOR ','),
        ']'
      )
    )
    FROM (
      SELECT AUTHOR.ID a
      FROM AUTHOR
    ) t
  ),
  '[]'
)

MySQL

ifnull(
  (
    SELECT json_merge_preserve(
      '[]',
      concat(
        '[',
        group_concat(a SEPARATOR ','),
        ']'
      )
    )
    FROM (
      SELECT AUTHOR.ID
      FROM AUTHOR
    ) t (a)
  ),
  '[]'
)

Spanner

(
  SELECT to_json(
    coalesce(
      array_agg(a), CAST(ARRAY[] AS array<int64>)
    )
  )
  FROM (
    SELECT AUTHOR.ID a
    FROM AUTHOR
  ) t
)

SQLite

(
  SELECT json_group_array(a)
  FROM (
    SELECT AUTHOR.ID a
    FROM AUTHOR
  ) t
)

SQLServer

coalesce(
  (
    SELECT json_query(('[' + string_agg(CAST(a AS varchar(max)), ',') + ']'))
    FROM (
      SELECT AUTHOR.ID
      FROM AUTHOR
    ) t (a)
  ),
  '[]'
)

Trino

coalesce(
  (
    SELECT cast(array_agg(a) AS json)
    FROM (
      SELECT AUTHOR.ID
      FROM AUTHOR
    ) t (a)
  ),
  json_parse('[]')
)

YugabyteDB

(
  SELECT json_agg(a)
  FROM (
    SELECT AUTHOR.ID
    FROM AUTHOR
  ) t (a)
)

ASE, Access, Aurora MySQL, Databricks, Exasol, Firebird, HSQLDB, Hana, Informix, MemSQL, Redshift, SQLDataWarehouse, 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!

The jOOQ Logo