Available in versions: Dev (3.16) | Latest (3.15) | 3.14 | 3.13 | 3.12

JSON_OBJECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The JSON_OBJECT function is used to produce simple JSON objects from scalar values, without aggregation.

SELECT json_object(
  KEY 'firstName' VALUE author.first_name, 
  KEY 'lastName'  VALUE author.last_name
)
FROM author
create.select(jsonObject(
          jsonEntry(inline("firstName"), AUTHOR.FIRST_NAME), 
          jsonEntry(inline("lastName"), AUTHOR.LAST_NAME))
      .from(AUTHOR)
      .fetch();

The result would look like this:

+--------------------------------------------+
| json_array                                 |
+--------------------------------------------+
| {"firstName":"Paulo","lastName":"Coelho"}  | 
| {"firstName":"George","lastName":"Orwell"} |
+--------------------------------------------+

Dialect support

This example using jOOQ:

jsonObject(jsonEntry(inline("firstName"), AUTHOR.FIRST_NAME))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, YUGABYTE
json_build_object('firstName', AUTHOR.FIRST_NAME)

-- DB2, H2, ORACLE
json_object(KEY 'firstName' VALUE AUTHOR.FIRST_NAME)

-- MARIADB, MYSQL, SQLITE
json_object('firstName', AUTHOR.FIRST_NAME)

-- SQLSERVER
(
  SELECT (
    SELECT *
    FROM (VALUES (AUTHOR.FIRST_NAME)) t (firstName)
    FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
  )
)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MEMSQL, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SYBASE, TERADATA, VERTICA
/* UNSUPPORTED */

(These are currently generated with jOOQ 3.16, see #10141), or translate your own on our website

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo