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.
NULL ON NULL
Supported by ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The JSON_ARRAY from query function has a NULL ON NULL clause to indicate that NULL values should be included in the output JSON array:
SELECT json_array( SELECT language.description FROM language NULL ON NULL ) FROM language
create.select(jsonObject(
select(LANGUAGE.CD).from(LANGUAGE))
.nullOnNull())
.from(LANGUAGE)
.fetch();
The result would look like this:
+------------------+ | json_array | +------------------+ | ["English",null] | +------------------+
Dialect support
This example using jOOQ:
jsonArray(select(LANGUAGE.DESCRIPTION).from(LANGUAGE)).nullOnNull()
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, ClickHouse, 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('[]', '$')
)
MySQL
ifnull(
(
SELECT json_merge_preserve(
'[]',
concat(
'[',
group_concat(json_quote(a) SEPARATOR ','),
']'
)
)
FROM (
SELECT LANGUAGE.DESCRIPTION
FROM LANGUAGE
) t (a)
),
cast('[]' AS json)
)
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
)
SQLServer
coalesce(
(
SELECT json_query(('[' + string_agg(cast(
('"' + replace(a, '"', '\"') + '"')
AS varchar(max)
), ',') + ']'))
FROM (
SELECT LANGUAGE.DESCRIPTION
FROM LANGUAGE
) t (a)
),
'[]'
)
Trino
coalesce(
(
SELECT cast(array_agg(a) AS json)
FROM (
SELECT LANGUAGE.DESCRIPTION
FROM LANGUAGE
) t (a)
),
json_parse('[]')
)
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!