Available in versions: Dev (3.21) | Latest (3.20) | 3.19 | 3.18 | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12

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 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(
  language.cd, language.description
  ABSENT ON NULL
)
FROM language
create.select(jsonArray(
          LANGUAGE.CD,
          LANGUAGE.DESCRIPTION)
          .absentOnNull())
      .from(LANGUAGE)
      .fetch();

The result would look like this:

+------------------+
| json_array       |
+------------------+
| ["EN","English"] |
| ["DE"]           |
+------------------+

Dialect support

This example using jOOQ:

jsonArray(LANGUAGE.CD, LANGUAGE.DESCRIPTION).absentOnNull()

Translates to the following dialect specific expressions:

Aurora Postgres, CockroachDB, Postgres, YugabyteDB

(
  SELECT json_agg(t.a)
  FROM (
    VALUES
      (LANGUAGE.CD),
      (LANGUAGE.DESCRIPTION)
  ) t (a)
  WHERE t.a IS NOT NULL
)

BigQuery, Spanner

json_strip_nulls(json_array(LANGUAGE.CD, LANGUAGE.DESCRIPTION))

DB2

(
  SELECT json_array(LANGUAGE.CD, LANGUAGE.DESCRIPTION ABSENT ON NULL)
  FROM SYSIBM.DUAL
)

DuckDB

cast(
  array_filter(
    ARRAY[
      cast(LANGUAGE.CD AS json),
      cast(LANGUAGE.DESCRIPTION AS json)
    ],
    e -> e IS NOT NULL
  )
  AS json
)

H2, Oracle

json_array(LANGUAGE.CD, LANGUAGE.DESCRIPTION ABSENT ON NULL)

MariaDB

coalesce(
  (
    SELECT json_merge_preserve(
      '[]',
      concat(
        '[',
        group_concat(json_extract(value, '$') SEPARATOR ','),
        ']'
      )
    )
    FROM JSON_TABLE(
      json_array(LANGUAGE.CD, LANGUAGE.DESCRIPTION),
      '$[*]'
      COLUMNS (value json PATH '$')
    ) t
    WHERE (
      value <> 'null'
      AND rand() IS NOT NULL
    )
  ),
  json_array()
)

Snowflake

array_construct_compact(LANGUAGE.CD, LANGUAGE.DESCRIPTION)

SQLite

(
  SELECT json_group_array(value) FILTER (WHERE (
    value IS NOT NULL
    AND key IS NOT NULL
  ))
  FROM json_tree(json_array(LANGUAGE.CD, LANGUAGE.DESCRIPTION))
)

Trino

cast(
  filter(
    ARRAY[
      cast(
        cast(LANGUAGE.CD AS varchar)
        AS json
      ),
      cast(LANGUAGE.DESCRIPTION AS json)
    ],
    e -> e IS NOT NULL
  )
  AS json
)

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