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.

ABSENT ON NULL

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

The JSON_ARRAY from query function has a ABSENT ON NULL clause to indicate that NULL values should not be contained in the output JSON array. Instead, the value should be removed from the array if it is NULL:

SELECT json_array(
  SELECT language.description FROM language
  ABSENT ON NULL
)
create.select(jsonArray(
          select(LANGUAGE.CD).from(LANGUAGE))
          .absentOnNull())
      .from(LANGUAGE)
      .fetch();

The result would look like this:

+-------------+
| json_array  |
+-------------+
| ["English"] |
+-------------+

Dialect support

This example using jOOQ:

jsonArray(select(LANGUAGE.DESCRIPTION).from(LANGUAGE)).absentOnNull()

Translates to the following dialect specific expressions:

Aurora Postgres, Postgres, YugabyteDB

coalesce(
  json_array(
    SELECT LANGUAGE.DESCRIPTION
    FROM LANGUAGE
    RETURNING json
  ),
  cast('[]' AS json)
)

BigQuery, DB2, H2, Oracle, Snowflake

json_array(
  SELECT LANGUAGE.DESCRIPTION
  FROM LANGUAGE
)

CockroachDB

coalesce(
  (
    SELECT json_agg(a)
    FROM (
      SELECT LANGUAGE.DESCRIPTION
      FROM LANGUAGE
    ) t (a)
  ),
  cast('[]' AS json)
)

DuckDB

coalesce(
  (
    SELECT to_json(array_agg(a))
    FROM (
      SELECT LANGUAGE.DESCRIPTION
      FROM LANGUAGE
    ) t (a)
  ),
  JSON '[]'
)

MariaDB

ifnull(
  (
    SELECT json_merge_preserve(
      '[]',
      concat(
        '[',
        group_concat(json_quote(a) SEPARATOR ','),
        ']'
      )
    )
    FROM (
      SELECT LANGUAGE.DESCRIPTION a
      FROM LANGUAGE
    ) t
  ),
  json_extract('[]', '$')
)

Spanner

(
  SELECT to_json(
    coalesce(
      array_agg(a), cast(ARRAY[] AS array<string>)
    )
  )
  FROM (
    SELECT LANGUAGE.DESCRIPTION a
    FROM LANGUAGE
  ) t
)

SQLite

(
  SELECT json_group_array(a)
  FROM (
    SELECT LANGUAGE.DESCRIPTION a
    FROM LANGUAGE
  ) t
)

Trino

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

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