14.17.4 Functions That Modify JSON Values (original) (raw)

14.17.4 Functions That Modify JSON Values

The functions in this section modify JSON values and return the result.

mysql> SET @j = '["a", ["b", "c"], "d"]';  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$[1]', 1);  
+----------------------------------+  
| JSON_ARRAY_APPEND(@j, '$[1]', 1) |  
+----------------------------------+  
| ["a", ["b", "c", 1], "d"]        |  
+----------------------------------+  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$[0]', 2);  
+----------------------------------+  
| JSON_ARRAY_APPEND(@j, '$[0]', 2) |  
+----------------------------------+  
| [["a", 2], ["b", "c"], "d"]      |  
+----------------------------------+  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$[1][0]', 3);  
+-------------------------------------+  
| JSON_ARRAY_APPEND(@j, '$[1][0]', 3) |  
+-------------------------------------+  
| ["a", [["b", 3], "c"], "d"]         |  
+-------------------------------------+  
mysql> SET @j = '{"a": 1, "b": [2, 3], "c": 4}';  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$.b', 'x');  
+------------------------------------+  
| JSON_ARRAY_APPEND(@j, '$.b', 'x')  |  
+------------------------------------+  
| {"a": 1, "b": [2, 3, "x"], "c": 4} |  
+------------------------------------+  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$.c', 'y');  
+--------------------------------------+  
| JSON_ARRAY_APPEND(@j, '$.c', 'y')    |  
+--------------------------------------+  
| {"a": 1, "b": [2, 3], "c": [4, "y"]} |  
+--------------------------------------+  
mysql> SET @j = '{"a": 1}';  
mysql> SELECT JSON_ARRAY_APPEND(@j, '$', 'z');  
+---------------------------------+  
| JSON_ARRAY_APPEND(@j, '$', 'z') |  
+---------------------------------+  
| [{"a": 1}, "z"]                 |  
+---------------------------------+  

In MySQL 5.7, this function was namedJSON_APPEND(). That name is no longer supported in MySQL 8.0.

mysql> SET @j = '["a", {"b": [1, 2]}, [3, 4]]';  
mysql> SELECT JSON_ARRAY_INSERT(@j, '$[1]', 'x');  
+------------------------------------+  
| JSON_ARRAY_INSERT(@j, '$[1]', 'x') |  
+------------------------------------+  
| ["a", "x", {"b": [1, 2]}, [3, 4]]  |  
+------------------------------------+  
mysql> SELECT JSON_ARRAY_INSERT(@j, '$[100]', 'x');  
+--------------------------------------+  
| JSON_ARRAY_INSERT(@j, '$[100]', 'x') |  
+--------------------------------------+  
| ["a", {"b": [1, 2]}, [3, 4], "x"]    |  
+--------------------------------------+  
mysql> SELECT JSON_ARRAY_INSERT(@j, '$[1].b[0]', 'x');  
+-----------------------------------------+  
| JSON_ARRAY_INSERT(@j, '$[1].b[0]', 'x') |  
+-----------------------------------------+  
| ["a", {"b": ["x", 1, 2]}, [3, 4]]       |  
+-----------------------------------------+  
mysql> SELECT JSON_ARRAY_INSERT(@j, '$[2][1]', 'y');  
+---------------------------------------+  
| JSON_ARRAY_INSERT(@j, '$[2][1]', 'y') |  
+---------------------------------------+  
| ["a", {"b": [1, 2]}, [3, "y", 4]]     |  
+---------------------------------------+  
mysql> SELECT JSON_ARRAY_INSERT(@j, '$[0]', 'x', '$[2][1]', 'y');  
+----------------------------------------------------+  
| JSON_ARRAY_INSERT(@j, '$[0]', 'x', '$[2][1]', 'y') |  
+----------------------------------------------------+  
| ["x", "a", {"b": [1, 2]}, [3, 4]]                  |  
+----------------------------------------------------+  

Earlier modifications affect the positions of the following elements in the array, so subsequent paths in the sameJSON_ARRAY_INSERT() call should take this into account. In the final example, the second path inserts nothing because the path no longer matches anything after the first insert.

mysql> SET @j = '{ "a": 1, "b": [2, 3]}';  
mysql> SELECT JSON_INSERT(@j, '$.a', 10, '$.c', '[true, false]');  
+----------------------------------------------------+  
| JSON_INSERT(@j, '$.a', 10, '$.c', '[true, false]') |  
+----------------------------------------------------+  
| {"a": 1, "b": [2, 3], "c": "[true, false]"}        |  
+----------------------------------------------------+  

The third and final value listed in the result is a quoted string and not an array like the second one (which is not quoted in the output); no casting of values to the JSON type is performed. To insert the array as an array, you must perform such casts explicitly, as shown here:

mysql> SELECT JSON_INSERT(@j, '$.a', 10, '$.c', CAST('[true, false]' AS JSON));  
+------------------------------------------------------------------+  
| JSON_INSERT(@j, '$.a', 10, '$.c', CAST('[true, false]' AS JSON)) |  
+------------------------------------------------------------------+  
| {"a": 1, "b": [2, 3], "c": [true, false]}                        |  
+------------------------------------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_MERGE('[1, 2]', '[true, false]');  
+---------------------------------------+  
| JSON_MERGE('[1, 2]', '[true, false]') |  
+---------------------------------------+  
| [1, 2, true, false]                   |  
+---------------------------------------+  
1 row in set, 1 warning (0.00 sec)  
mysql> SHOW WARNINGS\G  
*************************** 1. row ***************************  
  Level: Warning  
   Code: 1287  
Message: 'JSON_MERGE' is deprecated and will be removed in a future release. \  
 Please use JSON_MERGE_PRESERVE/JSON_MERGE_PATCH instead  
1 row in set (0.00 sec)  

For additional examples, see the entry forJSON_MERGE_PRESERVE().

For additional information, seeNormalization, Merging, and Autowrapping of JSON Values.

mysql> SELECT JSON_MERGE_PATCH('[1, 2]', '[true, false]');  
+---------------------------------------------+  
| JSON_MERGE_PATCH('[1, 2]', '[true, false]') |  
+---------------------------------------------+  
| [true, false]                               |  
+---------------------------------------------+  
mysql> SELECT JSON_MERGE_PATCH('{"name": "x"}', '{"id": 47}');  
+-------------------------------------------------+  
| JSON_MERGE_PATCH('{"name": "x"}', '{"id": 47}') |  
+-------------------------------------------------+  
| {"id": 47, "name": "x"}                         |  
+-------------------------------------------------+  
mysql> SELECT JSON_MERGE_PATCH('1', 'true');  
+-------------------------------+  
| JSON_MERGE_PATCH('1', 'true') |  
+-------------------------------+  
| true                          |  
+-------------------------------+  
mysql> SELECT JSON_MERGE_PATCH('[1, 2]', '{"id": 47}');  
+------------------------------------------+  
| JSON_MERGE_PATCH('[1, 2]', '{"id": 47}') |  
+------------------------------------------+  
| {"id": 47}                               |  
+------------------------------------------+  
mysql> SELECT JSON_MERGE_PATCH('{ "a": 1, "b":2 }',  
     >     '{ "a": 3, "c":4 }');  
+-----------------------------------------------------------+  
| JSON_MERGE_PATCH('{ "a": 1, "b":2 }','{ "a": 3, "c":4 }') |  
+-----------------------------------------------------------+  
| {"a": 3, "b": 2, "c": 4}                                  |  
+-----------------------------------------------------------+  
mysql> SELECT JSON_MERGE_PATCH('{ "a": 1, "b":2 }','{ "a": 3, "c":4 }',  
     >     '{ "a": 5, "d":6 }');  
+-------------------------------------------------------------------------------+  
| JSON_MERGE_PATCH('{ "a": 1, "b":2 }','{ "a": 3, "c":4 }','{ "a": 5, "d":6 }') |  
+-------------------------------------------------------------------------------+  
| {"a": 5, "b": 2, "c": 4, "d": 6}                                              |  
+-------------------------------------------------------------------------------+  

You can use this function to remove a member by specifyingnull as the value of the same member in the second argument, as shown here:

mysql> SELECT JSON_MERGE_PATCH('{"a":1, "b":2}', '{"b":null}');  
+--------------------------------------------------+  
| JSON_MERGE_PATCH('{"a":1, "b":2}', '{"b":null}') |  
+--------------------------------------------------+  
| {"a": 1}                                         |  
+--------------------------------------------------+  

This example shows that the function operates in a recursive fashion; that is, values of members are not limited to scalars, but rather can themselves be JSON documents:

mysql> SELECT JSON_MERGE_PATCH('{"a":{"x":1}}', '{"a":{"y":2}}');  
+----------------------------------------------------+  
| JSON_MERGE_PATCH('{"a":{"x":1}}', '{"a":{"y":2}}') |  
+----------------------------------------------------+  
| {"a": {"x": 1, "y": 2}}                            |  
+----------------------------------------------------+  

JSON_MERGE_PATCH() is supported in MySQL 8.0.3 and later.
JSON_MERGE_PATCH() compared with JSON_MERGE_PRESERVE(). The behavior of JSON_MERGE_PATCH() is the same as that ofJSON_MERGE_PRESERVE(), with the following two exceptions:

mysql> SET @x = '{ "a": 1, "b": 2 }',  
     >     @y = '{ "a": 3, "c": 4 }',  
     >     @z = '{ "a": 5, "d": 6 }';  
mysql> SELECT  JSON_MERGE_PATCH(@x, @y, @z)    AS Patch,  
    ->         JSON_MERGE_PRESERVE(@x, @y, @z) AS Preserve\G  
*************************** 1. row ***************************  
   Patch: {"a": 5, "b": 2, "c": 4, "d": 6}  
Preserve: {"a": [1, 3, 5], "b": 2, "c": 4, "d": 6}  
mysql> SELECT JSON_MERGE_PRESERVE('[1, 2]', '[true, false]');  
+------------------------------------------------+  
| JSON_MERGE_PRESERVE('[1, 2]', '[true, false]') |  
+------------------------------------------------+  
| [1, 2, true, false]                            |  
+------------------------------------------------+  
mysql> SELECT JSON_MERGE_PRESERVE('{"name": "x"}', '{"id": 47}');  
+----------------------------------------------------+  
| JSON_MERGE_PRESERVE('{"name": "x"}', '{"id": 47}') |  
+----------------------------------------------------+  
| {"id": 47, "name": "x"}                            |  
+----------------------------------------------------+  
mysql> SELECT JSON_MERGE_PRESERVE('1', 'true');  
+----------------------------------+  
| JSON_MERGE_PRESERVE('1', 'true') |  
+----------------------------------+  
| [1, true]                        |  
+----------------------------------+  
mysql> SELECT JSON_MERGE_PRESERVE('[1, 2]', '{"id": 47}');  
+---------------------------------------------+  
| JSON_MERGE_PRESERVE('[1, 2]', '{"id": 47}') |  
+---------------------------------------------+  
| [1, 2, {"id": 47}]                          |  
+---------------------------------------------+  
mysql> SELECT JSON_MERGE_PRESERVE('{ "a": 1, "b": 2 }',  
     >    '{ "a": 3, "c": 4 }');  
+--------------------------------------------------------------+  
| JSON_MERGE_PRESERVE('{ "a": 1, "b": 2 }','{ "a": 3, "c":4 }') |  
+--------------------------------------------------------------+  
| {"a": [1, 3], "b": 2, "c": 4}                                |  
+--------------------------------------------------------------+  
mysql> SELECT JSON_MERGE_PRESERVE('{ "a": 1, "b": 2 }','{ "a": 3, "c": 4 }',  
     >    '{ "a": 5, "d": 6 }');  
+----------------------------------------------------------------------------------+  
| JSON_MERGE_PRESERVE('{ "a": 1, "b": 2 }','{ "a": 3, "c": 4 }','{ "a": 5, "d": 6 }') |  
+----------------------------------------------------------------------------------+  
| {"a": [1, 3, 5], "b": 2, "c": 4, "d": 6}                                         |  
+----------------------------------------------------------------------------------+  

This function was added in MySQL 8.0.3 as a synonym forJSON_MERGE(). TheJSON_MERGE() function is now deprecated, and is subject to removal in a future release of MySQL.
This function is similar to but differs fromJSON_MERGE_PATCH() in significant respects; seeJSON_MERGE_PATCH() compared with JSON_MERGE_PRESERVE(), for more information.

mysql> SET @j = '["a", ["b", "c"], "d"]';  
mysql> SELECT JSON_REMOVE(@j, '$[1]');  
+-------------------------+  
| JSON_REMOVE(@j, '$[1]') |  
+-------------------------+  
| ["a", "d"]              |  
+-------------------------+  
mysql> SET @j = '{ "a": 1, "b": [2, 3]}';  
mysql> SELECT JSON_REPLACE(@j, '$.a', 10, '$.c', '[true, false]');  
+-----------------------------------------------------+  
| JSON_REPLACE(@j, '$.a', 10, '$.c', '[true, false]') |  
+-----------------------------------------------------+  
| {"a": 10, "b": [2, 3]}                              |  
+-----------------------------------------------------+  
mysql> SELECT JSON_REPLACE(NULL, '$.a', 10, '$.c', '[true, false]');  
+-------------------------------------------------------+  
| JSON_REPLACE(NULL, '$.a', 10, '$.c', '[true, false]') |  
+-------------------------------------------------------+  
| NULL                                                  |  
+-------------------------------------------------------+  
mysql> SELECT JSON_REPLACE(@j, NULL, 10, '$.c', '[true, false]');  
+----------------------------------------------------+  
| JSON_REPLACE(@j, NULL, 10, '$.c', '[true, false]') |  
+----------------------------------------------------+  
| NULL                                               |  
+----------------------------------------------------+  
mysql> SELECT JSON_REPLACE(@j, '$.a', NULL, '$.c', '[true, false]');  
+-------------------------------------------------------+  
| JSON_REPLACE(@j, '$.a', NULL, '$.c', '[true, false]') |  
+-------------------------------------------------------+  
| {"a": null, "b": [2, 3]}                              |  
+-------------------------------------------------------+  
mysql> SET @j = '{ "a": 1, "b": [2, 3]}';  
mysql> SELECT JSON_SET(@j, '$.a', 10, '$.c', '[true, false]');  
+-------------------------------------------------+  
| JSON_SET(@j, '$.a', 10, '$.c', '[true, false]') |  
+-------------------------------------------------+  
| {"a": 10, "b": [2, 3], "c": "[true, false]"}    |  
+-------------------------------------------------+  
mysql> SELECT JSON_INSERT(@j, '$.a', 10, '$.c', '[true, false]');  
+----------------------------------------------------+  
| JSON_INSERT(@j, '$.a', 10, '$.c', '[true, false]') |  
+----------------------------------------------------+  
| {"a": 1, "b": [2, 3], "c": "[true, false]"}        |  
+----------------------------------------------------+  
mysql> SELECT JSON_REPLACE(@j, '$.a', 10, '$.c', '[true, false]');  
+-----------------------------------------------------+  
| JSON_REPLACE(@j, '$.a', 10, '$.c', '[true, false]') |  
+-----------------------------------------------------+  
| {"a": 10, "b": [2, 3]}                              |  
+-----------------------------------------------------+  
mysql> SET @j = '"abc"';  
mysql> SELECT @j, JSON_UNQUOTE(@j);  
+-------+------------------+  
| @j    | JSON_UNQUOTE(@j) |  
+-------+------------------+  
| "abc" | abc              |  
+-------+------------------+  
mysql> SET @j = '[1, 2, 3]';  
mysql> SELECT @j, JSON_UNQUOTE(@j);  
+-----------+------------------+  
| @j        | JSON_UNQUOTE(@j) |  
+-----------+------------------+  
| [1, 2, 3] | [1, 2, 3]        |  
+-----------+------------------+  

The following set of examples shows howJSON_UNQUOTE handles escapes withNO_BACKSLASH_ESCAPES disabled and enabled:

mysql> SELECT @@sql_mode;  
+------------+  
| @@sql_mode |  
+------------+  
|            |  
+------------+  
mysql> SELECT JSON_UNQUOTE('"\\t\\u0032"');  
+------------------------------+  
| JSON_UNQUOTE('"\\t\\u0032"') |  
+------------------------------+  
|       2                           |  
+------------------------------+  
mysql> SET @@sql_mode = 'NO_BACKSLASH_ESCAPES';  
mysql> SELECT JSON_UNQUOTE('"\\t\\u0032"');  
+------------------------------+  
| JSON_UNQUOTE('"\\t\\u0032"') |  
+------------------------------+  
| \t\u0032                     |  
+------------------------------+  
mysql> SELECT JSON_UNQUOTE('"\t\u0032"');  
+----------------------------+  
| JSON_UNQUOTE('"\t\u0032"') |  
+----------------------------+  
|       2                         |  
+----------------------------+