In MariaDB, JSON_MERGE_PATCH()
is a built-in function that merges two or more JSON documents and returns the result.
The JSON_MERGE_PATCH()
function is an RFC 7396-compliant replacement for the JSON_MERGE()
function, which has been deprecated.
Syntax
The syntax goes like this:
JSON_MERGE_PATCH(json_doc, json_doc[, json_doc] ...)
Where json_doc
are the JSON documents to merge.
Example
Here’s an example to demonstrate.
SELECT JSON_MERGE_PATCH('{"name":"Wag"}', '{"type":"Dog"}');
Result:
+------------------------------------------------------+ | JSON_MERGE_PATCH('{"name":"Wag"}', '{"type":"Dog"}') | +------------------------------------------------------+ | {"name": "Wag", "type": "Dog"} | +------------------------------------------------------+
We can see that the two documents have been merged into one.
Here’s an example that merges three documents:
SELECT JSON_MERGE_PATCH(
'{ "name" : "Wag" }',
'{ "type" : "Dog" }',
'{ "score" : [ 9, 7, 8 ] }'
) AS Result;
Result:
+----------------------------------------------------+ | Result | +----------------------------------------------------+ | {"name": "Wag", "type": "Dog", "score": [9, 7, 8]} | +----------------------------------------------------+
Arrays
The JSON_MERGE_PATCH()
function does not merge arrays:
SELECT JSON_MERGE_PATCH(
'[1,2,3]',
'[4,5,6]'
) AS Result;
Result:
+-----------+ | Result | +-----------+ | [4, 5, 6] | +-----------+
This is in contrast to the (deprecated) JSON_MERGE()
function and its synonym JSON_MERGE_PRESERVE()
, both of which do merge arrays.
Format of the Result
You might have noticed that JSON_MERGE_PATCH()
adds spaces to the resulting document. If this is a problem, you can use JSON_COMPACT()
to remove the space.
Example:
SELECT
JSON_COMPACT(
JSON_MERGE_PATCH(
'{"name":"Wag"}',
'{"type":"Dog"}',
'{"score":[9,7,8]}'
)
) AS Result;
Result:
+---------------------------------------------+ | Result | +---------------------------------------------+ | {"name":"Wag","type":"Dog","score":[9,7,8]} | +---------------------------------------------+
But if you need to go the other way and get extra formatting, such as indented structures, try the JSON_DETAILED()
function.
SELECT
JSON_DETAILED(
JSON_MERGE_PATCH(
'{ "name" : "Wag" }',
'{ "type" : "Dog" }',
'{ "score" : [ 9, 7, 8 ] }'
)
) AS Result;
Result:
+---------------------------------------+ | Result | +---------------------------------------+ | { "name": "Wag", "type": "Dog", "score": [ 9, 7, 8 ] } | +---------------------------------------+
Null Argument
If any argument is NULL
, the result is NULL
:
SELECT
JSON_MERGE_PATCH('{"a":1}', null) AS a,
JSON_MERGE_PATCH(null, '{"a":1}') AS b,
JSON_MERGE_PATCH(null, null) AS c;
Result:
+------+------+------+ | a | b | c | +------+------+------+ | NULL | NULL | NULL | +------+------+------+
Incorrect Parameter Count
Calling the function without any arguments results in an error:
SELECT JSON_MERGE_PATCH();
Result:
ERROR 1582 (42000): Incorrect parameter count in the call to native function 'JSON_MERGE_PATCH'
It’s the same when you provide just one argument:
SELECT JSON_MERGE_PATCH('{"a":1}');
Result:
ERROR 1582 (42000): Incorrect parameter count in the call to native function 'JSON_MERGE_PATCH'