How to append additional key value pair to a JSON object in MySQL or MariaDB

Written by - 0 comments

Published on - Listed in MySQL MariaDB Database Linux Coding


Certain applications use JSON in MySQL tables. This allows to store all kinds of relevant information, separated into keys and values, in one data field.

In this particular example, the application (Invoice Ninja) uses a JSON object in the settings column in the clients table. This defines specific settings per client.

MariaDB [invoiceninja]> SELECT id,settings FROM clients LIMIT 0,5;
+-----+-----------------------------------------------------------------+
| id  | settings                                                        |
+-----+-----------------------------------------------------------------+
| 223 | {"currency_id":"17"}                                            |
| 224 | {"currency_id":"17"}                                            |
| 225 | {"currency_id":"17"}                                            |
| 226 | {"currency_id":"17"}                                            |
| 227 | {"currency_id":"17"}                                            |
+-----+-----------------------------------------------------------------+
5 rows in set (0.001 sec)

When changing a client in the user interface, the relevant setting is appended in this JSON object:

MariaDB [invoiceninja]> SELECT id,settings FROM clients WHERE settings LIKE '%payment%' LIMIT 0,5;
+-----+----------------------------------------------+
| id  | settings                                     |
+-----+----------------------------------------------+
| 235 | {"currency_id": "17", "payment_terms": "30"} |
| 241 | {"currency_id": "17", "payment_terms": "10"} |
| 243 | {"currency_id": "17", "payment_terms": "30"} |
| 244 | {"currency_id": "17", "payment_terms": "10"} |
| 246 | {"currency_id": "17", "payment_terms": "30"} |
+-----+----------------------------------------------+
5 rows in set (0.001 sec)

To append an additional setting (key/value pair) to the JSON object, MySQL is able to handle this with the JSON_MERGE function.

function JSON_MERGE(object1, object2, ...);

JSON_MERGE uses multiple JSON objects from the input (object1, object2, etc) and merges them into one object. Important to note here is that the objects need to be defined as JSON object including the curly brackets:

JSON_MERGE('{"key":"value", "key2":true}', '{"foo":"bar", "teddy": true}')

Now to append an additional key value pair {"send_reminders": true} to all entries in the clients table, use JSON_MERGE:

MariaDB [invoiceninja]> UPDATE clients SET settings = JSON_MERGE(settings, '{"send_reminders":true}');
Query OK, 119 rows affected (0.008 sec)
Rows matched: 119  Changed: 119  Warnings: 0

As first object the JSON object from the settings column is read. The second object is the hard-coded JSON object to enable reminders. After the command was run, each client now has reminders enabled:

MariaDB [invoiceninja]> SELECT id,settings FROM clients LIMIT 0,5;
+-----+-----------------------------------------------+
| id  | settings                                      |
+-----+-----------------------------------------------+
| 223 | {"currency_id": "17", "send_reminders": true} |
| 224 | {"currency_id": "17", "send_reminders": true} |
| 225 | {"currency_id": "17", "send_reminders": true} |
| 226 | {"currency_id": "17", "send_reminders": true} |
| 227 | {"currency_id": "17", "send_reminders": true} |
+-----+-----------------------------------------------+
5 rows in set (0.000 sec)

Definitely a much faster way than manually editing each client in the application.


Add a comment

Show form to leave a comment

Comments (newest first)

No comments yet.