ftisiot ideas about food and life
who talks suggestions soft json-pg json-mysql

How to extract an item from an array in a JSON object in MySQL

Published Jul 21, 2023 by in Mysql, Json, Extract, Array at https://ftisiot.net/mysqljson/how-to-extract-field-from-array-json-mysql/

To extract an item from an array in MySQL you need to use the -> operator and the [item_number] JSON Path Syntax.

NOTE: more info is available in the MySQL JSON functions documentation page

👉 Need a FREE MySQL database? check Aiven's free plans👈

The dataset

The dataset is the following:

{
    "id": 778,
    "shop": "Luigis Pizza",
    "name": "Edward Olson",
    "phoneNumbers":
        ["(935)503-3765x4154","(935)12345"],
    "address": "Unit 9398 Box 2056 DPO AP 24022",
    "image": null,
    "pizzas": [
        {
            "pizzaName": "Salami",
            "additionalToppings": ["🥓", "🌶️"]
        },
        {
            "pizzaName": "Margherita",
            "additionalToppings": ["🍌", "🌶️", "🍍"]
        }
    ]
}
Check out the description of the fields The following examples use a pizza order dataset with an order having:
  • id: 778
  • shop: “Luigis Pizza”
  • name: “Edward Olson”
  • phoneNumbers:["(935)503-3765x4154","(935)12345"]
  • address: “Unit 9398 Box 2056 DPO AP 24022”
  • image: null
  • and two pizzas contained in the pizzas item:
[
    {
        "pizzaName": "Salami",
        "additionalToppings": ["🥓", "🌶️"]
    },
    {
        "pizzaName": "Margherita",
        "additionalToppings": ["🍌", "🌶️", "🍍"]
    }
]
If you want to reproduce the examples, check how to recreate the dataset

It can be recreated with the following script:

create table test(id serial primary key, json_data json);

insert into test(json_data) values (
'{
    "id": 778,
    "shop": "Luigis Pizza",
    "name": "Edward Olson",
    "phoneNumbers":
        ["(935)503-3765x4154","(935)12345"],
    "address": "Unit 9398 Box 2056 DPO AP 24022",
    "image": null,
    "pizzas": [
        {
            "pizzaName": "Salami",
            "additionalToppings": ["🥓", "🌶️"]
        },
        {
            "pizzaName": "Margherita",
            "additionalToppings": ["🍌", "🌶️", "🍍"]
        }
    ]
}');

Extract an item from a JSON array with the -> operator

Using the -> operator in conjunction with the [item_number] JSON Path sintax, we can extract from an array. The [item_number] syntax follows the JSON standards, therefore the array starting index is 0. The second pizza in the order can be extracted with

select 
    json_data -> '$.pizzas[1]' second_pizza
    from test;

In the above query

  • json_data -> '$.pizzas' extracts the pizzas field
  • the additional [1] extracts the second pizza (index starts from 0)

Result

+--------------------------------------------------------------------------------+
| second_pizza                                                                   |
+--------------------------------------------------------------------------------+
| {"pizzaName": "Margherita", "additionalToppings": ["🍌", "🌶️", "🍍"]}          |
+--------------------------------------------------------------------------------+

Review all the JSON MySQL use-cases listed in the main page


Francesco Tisiot

Mastodon Francesco comes from Verona, Italy and works as a Staff Developer Advocate at Aiven. With his many years of experience as a data analyst, he has stories to tell and advice for data-wranglers everywhere. Francesco loves sharing knowledge with others as a speaker and writer, and is on a mission to defend the world from bad Italian food!

Story logo

© 2023