INCLUDE_NULL_VALUES directive
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The INCLUDE_NULL_VALUES
directive allows for including NULL
values in the output document.
By default, NULL
values are omitted from the FOR JSON
document output. Consider this query:
SELECT id, nullif(cd, 'en') AS cd FROM langauge ORDER BY id FOR JSON AUTO
create.select( LANGUAGE.ID, nullif(LANGUAGE.CD, "en").as(LANGUAGE.CD)) .from(LANGUAGE) .orderBy(LANGUAGE.ID) .forJSON().auto() .fetch();
This query produces a document like this:
[ {"id":1}, {"id":2,"cd":"de"}, {"id":3,"cd":"fr"}, {"id":4,"cd":"pt"} ]
If you prefer explicit NULL
values, write:
SELECT id, nullif(cd, 'en') AS cd FROM langauge ORDER BY id FOR JSON AUTO, INCLUDE_NULL_VALUES
create.select( LANGUAGE.ID, nullif(LANGUAGE.CD, "en").as(LANGUAGE.CD)) .from(LANGUAGE) .orderBy(LANGUAGE.ID) .forJSON().auto().includeNullValues() .fetch();
This query produces a document like this:
[ {"id":1,"cd":null}, {"id":2,"cd":"de"}, {"id":3,"cd":"fr"}, {"id":4,"cd":"pt"} ]
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).orderBy(BOOK.ID).forJSON().auto().includeNullValues()
Translates to the following dialect specific expressions:
Aurora Postgres, CockroachDB, Postgres, YugabyteDB
SELECT json_agg(json_build_object('ID', ID)) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
ClickHouse
SELECT toJSONString(CAST(groupArray(toJSONString(map('ID', ID))) AS Array(JSON))) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
DB2
SELECT CAST(('[' || listagg( json_object( KEY 'ID' VALUE ID NULL ON NULL ), ',' ) || ']') AS varchar(32672)) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
H2
SELECT json_arrayagg(json_object( KEY 'ID' VALUE ID NULL ON NULL )) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
MariaDB, MySQL
SET @t = @@group_concat_max_len; SET @@group_concat_max_len = 4294967295; SELECT json_merge_preserve( '[]', concat( '[', group_concat(json_object('ID', ID) SEPARATOR ','), ']' ) ) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t; SET @@group_concat_max_len = @t;
Oracle
SELECT json_arrayagg(json_object( KEY 'ID' VALUE ID NULL ON NULL RETURNING clob ) FORMAT JSON RETURNING clob) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
SQLServer
SELECT ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID FOR JSON AUTO, INCLUDE_NULL_VALUES )
Trino
SELECT cast(array_agg(CAST(map_from_entries(ARRAY[row( 'ID', CAST(ID AS json) )]) AS json)) AS json) FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) t
ASE, Access, Aurora MySQL, BigQuery, Databricks, Derby, DuckDB, Exasol, Firebird, HSQLDB, Hana, Informix, MemSQL, Redshift, SQLDataWarehouse, SQLite, Snowflake, 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!