Available in versions: Dev (3.20) | Latest (3.19) | 3.18

JSON_INSERT function

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

The MySQL style JSON_INSERT function is a function that adds but doesn't replace (JSON_REPLACE) a value in a JSON document, given a JSON path.

SELECT
  JSON_INSERT('{"a":1}', '$.a', 2),
  JSON_INSERT('{"a":1}', '$.b', 2)
create.select(
           jsonInsert(val(json("{\"a\":1}")), "$.a", 2),
           jsonInsert(val(json("{\"a\":1}")), "$.b", 2)).fetch();

The result would look like this:

+-------------+---------------+
| json_insert | json_insert   |
+-------------+---------------+
| {"a":1}     | {"a":1,"b":2} |
+-------------+---------------+

Dialect support

This example using jOOQ:

jsonInsert(val(json("{\"a\":2}")), "$.a", 2)

Translates to the following dialect specific expressions:

MariaDB, MySQL, SQLite

json_insert('{"a":2}', '$.a', 2)

Oracle

json_transform('{"a":2}', INSERT '$.a' = 2 IGNORE ON EXISTING)

SQLServer

CASE
  WHEN coalesce(
    json_query('{"a":2}', '$.a'),
    json_value('{"a":2}', '$.a')
  ) IS NOT NULL THEN '{"a":2}'
  ELSE json_modify(
    json_modify('{"a":2}', '$.a', ''),
    ('strict ' + '$.a'),
    2
  )
END

ASE, Access, Aurora MySQL, Aurora Postgres, BigQuery, ClickHouse, CockroachDB, DB2, Derby, DuckDB, Exasol, Firebird, H2, HSQLDB, Hana, Informix, MemSQL, Postgres, Redshift, SQLDataWarehouse, Snowflake, Sybase, Teradata, Trino, Vertica, YugabyteDB

/* UNSUPPORTED */

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

References to this page

Feedback

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

The jOOQ Logo