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
ABSENT ON NULL
Supported by ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The JSON_OBJECT function has a ABSENT ON NULL clause to indicate that NULL values should not be contained in the output JSON document. Instead, the key should be removed from the document if the value is NULL:
SELECT json_object( KEY 'cd' VALUE language.cd, KEY 'desc' VALUE language.description ABSENT ON NULL ) FROM language
create.select(jsonObject(
key("cd").value(LANGUAGE.CD),
key("desc").value(LANGUAGE.DESCRIPTION))
.absentOnNull())
.from(LANGUAGE)
.fetch();
The result would look like this:
+------------------------------+
| json_object |
+------------------------------+
| {"cd":"EN","desc":"English"} |
| {"cd":"DE"} |
+------------------------------+
Dialect support
This example using jOOQ:
jsonObject("description", LANGUAGE.DESCRIPTION).absentOnNull()
Translates to the following dialect specific expressions:
Aurora Postgres, CockroachDB, Postgres, YugabyteDB
json_strip_nulls(json_build_object('description', LANGUAGE.DESCRIPTION))
BigQuery, Spanner
json_strip_nulls(json_object('description', LANGUAGE.DESCRIPTION))
DB2, H2, Oracle
json_object( KEY 'description' VALUE LANGUAGE.DESCRIPTION ABSENT ON NULL )
DuckDB
cast(
map_from_entries(array_filter(
ARRAY[row(
'description',
cast(LANGUAGE.DESCRIPTION AS json)
)],
e -> e[2] IS NOT NULL
))
AS json
)
MariaDB
json_object('description', LANGUAGE.DESCRIPTION)
MySQL
(
SELECT coalesce(
json_objectagg(jt.k, json_extract(
j.o,
concat('$."', jt.k, '"')
)),
json_object()
)
FROM
(
SELECT json_object('description', LANGUAGE.DESCRIPTION) o
) j,
JSON_TABLE(
json_keys(j.o),
'$[*]'
COLUMNS (k text PATH '$')
) jt
WHERE json_extract(
j.o,
concat('$."', jt.k, '"')
) <> cast('null' AS json)
)
Snowflake
object_construct('description', LANGUAGE.DESCRIPTION)
SQLite
(
SELECT json_group_object(key, value) FILTER (WHERE (
value IS NOT NULL
AND key IS NOT NULL
))
FROM json_tree(json_object('description', LANGUAGE.DESCRIPTION))
)
SQLServer
json_object( 'description': LANGUAGE.DESCRIPTION ABSENT ON NULL )
Trino
cast(
map_from_entries(filter(
ARRAY[row(
'description',
cast(LANGUAGE.DESCRIPTION AS json)
)],
e -> e[2] IS NOT NULL
))
AS json
)
ASE, Access, Aurora MySQL, ClickHouse, 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!