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

JSON_SET function

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

The MySQL style JSON_SET function is a function that adds (like JSON_INSERT) or replaces (JSON_REPLACE) a value in a JSON document, given a JSON path.

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

The result would look like this:

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

Dialect support

This example using jOOQ:

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

Translates to the following dialect specific expressions:

-- MARIADB, MYSQL, SQLITE
json_set('{"a":1}', '$.a', 2)

-- ORACLE
json_transform('{"a":1}', SET '$.a' = 2)

-- SQLSERVER
json_modify(
  json_modify('{"a":1}', '$.a', ''),
  ('strict ' + '$.a'),
  2
)

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, 
-- HSQLDB, INFORMIX, MEMSQL, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
/* UNSUPPORTED */

(These are currently generated with jOOQ 3.19, 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