Loader

How to Import JSON to Excel Using VBA

import json to excel

How to Import JSON to Excel Using VBA

Howdee! It’s becoming increasingly more common for data to be generated in a JSON format as opposed to XML. XML was widely used for years, but recently JSON has started to become the preferred method of data exchange. Many REST APIs have the option to return both but the majority that I interact with default to returning JSON formatted data. Therefore, as excel ninjas, it’s important to understand how to import JSON to Excel for analysis. Before we begin on that route, let’s take a quick moment to talk about what JSON is for those that aren’t familiar with it.

Curious how to do this in VSTO? Click Here!

What is JSON?

JSON stands for JavaScript Object Notation and is a lightweight data-interchange format. In layman’s terms, it is a string of text that represents a universal data structure. It is easy for humans to read (when formatted properly) and, because of the universal structure, it is very easy and fast for machines to parse and generate. It’s made simple because JSON, at it’s most basic, is only two data types. It is made up of objects, or arrays, or a combination of both. Objects are made up of key/value pairs (often called a dictionary) and arrays are simply collections of values or objects separated by a comma.

It’s important to note that object/dictionary and array are the terminology applicable to the .NET language. Other languages might have other terminology such as hash table for object, or vector for an array. This site gives a great high level, cross-language overview of JSON.

JSON Object

A JSON object always begins with { and ends with }. The key is separated from its value with a colon (“:”). The key/value pairs will then be separated by commas all within the curly brackets. In the image below, the first key “color” corresponds to its value “red”, while the second key “value” corresponds to the red hex code “#f00”. Hopefully you can see why this might be called a dictionary as you look up the key (word to define) to get its value (definition of the word).

import json to excel

JSON Array

A JSON array, in its simplest form, is a list of values separated by a comma that begins with [ and ends with ]. In the below image, the JSON array is a list of string data points. We can see that they are colors but there is no key in this example explicitly telling that this string represents a color. Therefore, JSON is most commonly seen as a combination of arrays and objects.

import json to excel

JSON Objects & Arrays Together

Most of the time, JSON is returned as an array of objects. If you recall, an object always begins and ends with curly brackets. Therefore, the array of objects would have several objects enclosed in curly brackets that are separated by commas and all objects are enclosed in normal brackets (the array). That looks like this image:

import json to excel

In this example, each object represents a color and its corresponding hex code. In Excel, this would likely be two columns of data. One column for color, and the other for its hex code value. Now that you’re more familiar with JSON data structure, let’s learn how to import JSON to Excel!

Setup JSON to Excel

There are several libraries out there to help you import JSON to Excel. The most popular of these is VBA-JSON which is available here on GitHub. This library will do most of the hard work of parsing the JSON string to a dictionary for you and then you can write the values to an excel worksheet. When you download the latest release, you’ll need to import the “JsonConverter.bas” file to your VBA project. This GIF shows how that is accomplished. You will also need to add a  reference to the “Microsoft Scripting Runtime” by clicking tools from the ribbon, selecting references and checking the box for Microsoft Scripting Runtime as shown in the screen grab.

Once you have completed both steps, insert a new module into your project and title it whatever you like. To get started, we need to dimension some variables to use later.

Dim ws As Worksheet
Dim jsonText As String
Dim jsonObject As Object

The ws variable will represent a worksheet in excel. In this example, we will use this worksheet to both read in our JSON string from and write the parsed JSON to Excel. To assign a worksheet to this variable, set it like this:

Set ws = Worksheets("JSON to Excel Example")

The jsonText variable will represent our string of valid JSON data. For this example, I’ve pasted that string of colors and hex codes we looked at earlier into cell A1 on the JSON to Excel Example tab. To assign that string to a variable, type this code:

jsonText = ws.Cells(1, 1)

This step is not necessary for the code to work for us. We could simply reference the cell in the worksheet that contains the JSON. However, most of the time you’ll be returning your JSON string from another data source, most likely a HTTP GET Web Call. If you’re not familiar with HTTP Requests in VBA, click here to learn more.

Lastly, to put the JSON string into the jsonObject, we will use one of the methods contained in the JsonConverter file you imported to begin this example. Since the builder of this library made all of the subroutines public, it is callable from the module this code is in. That call looks like this:

Set jsonObject = JsonConverter.ParseJson(jsonText)

This call instructs the JsonConverter module to parse the JSON string you’ve passed it using the jsonText variable to a collection of dictionaries that we can now access. Now that we’ve finished our setup, we can start learning to import JSON to Excel in the next section.

Import JSON to Excel

The code to import JSON to Excel might sound daunting, but it is much easier than it sounds. At a high level, all you have to do is loop through the jsonObject you’ve created, and write each dictionary value to the sheet. The wonderful thing about dictionaries, is this is easy to do with a for each loop. I’ve added a couple of variables and a for each loop to our code and the result is this:

Sub JsonToExcelExample()
Dim jsonText As String
Dim jsonObject As Object, item As Object
Dim i As Long
Dim ws As Worksheet

Set ws = Worksheets("JSON to Excel Example")

jsonText = ws.Cells(1, 1)

Set jsonObject = JsonConverter.ParseJson(jsonText)

i = 3

ws.Cells(2, 1) = "Color"
ws.Cells(2, 2) = "Hex Code"

For Each item In jsonObject
    ws.Cells(i, 1) = item("color")
    ws.Cells(i, 2) = item("value")
    i = i + 1
Next

End Sub

I set a counter variable, i, that I can use to tell the loop which row to write the data to. Next, create my column headers for the data. Then, for each “item” in the jsonObject write that dictionaries values to the cell row I indicate and increment my counter variable. That’s it! The results of our import JSON to Excel code looks like this:

import json to excel

As you can see, we’ve turned that odd-looking string of text in cell A1 to an easy to understand table of data with just a few lines of code!

Understanding JSON to Excel (Advanced)

Now, I do want to point out that understanding the structure of the JSON you’ll be parsing is very important. Within the for each loop, the code can access the value of each object by referencing its key. This goes back to understanding the key/value pair relationship of JSON and the dictionary structure to which it is parsed. The reason I stress this so much is because, when you’re pulling back more complex looking JSON, you may need to have multiple levels of dictionary references to access the value you want. There may also be times when you have to nest for loops when you have an array of objects with arrays of objects nested inside each object.

For example, let’s look at an example where the JSON is structured as a single object with key “data” and the value is an array of data about employee’s and their organizations:

import json to excel

As you can see, we have an object with an array nested inside. Some objects in the array contains other nested objects as well. This multi-tiered data structure is very common when pulling data from a REST service and was very confusing to me when I first began trying to import JSON to Excel. Let’s examine what the code looks like for this scenario before we dive any deeper.

Sub JsonToExcelAdvancedExample()
Dim jsonText As String
Dim jsonObject As Object, item As Object
Dim i As Long
Dim ws As Worksheet

Set ws = Worksheets("JSON to Excel Advanced Example")

jsonText = ws.Cells(1, 1)

Set jsonObject = JsonConverter.ParseJson(jsonText)

i = 3

ws.Cells(2, 1) = "id"
ws.Cells(2, 2) = "Name"
ws.Cells(2, 3) = "Username"
ws.Cells(2, 4) = "Email"
ws.Cells(2, 5) = "Street Address"
ws.Cells(2, 6) = "Suite"
ws.Cells(2, 7) = "City"
ws.Cells(2, 8) = "Zipcode"
ws.Cells(2, 9) = "Phone"
ws.Cells(2, 10) = "Website"
ws.Cells(2, 11) = "Company"

For Each item In jsonObject("data")
    ws.Cells(i, 1) = item("id")
    ws.Cells(i, 2) = item("name")
    ws.Cells(i, 3) = item("username")
    ws.Cells(i, 4) = item("email")
    ws.Cells(i, 5) = item("address")("street")
    ws.Cells(i, 6) = item("address")("suite")
    ws.Cells(i, 7) = item("address")("city")
    ws.Cells(i, 8) = item("address")("zipcode")
    ws.Cells(i, 9) = item("phone")
    ws.Cells(i, 10) = item("website")
    ws.Cells(i, 11) = item("company")("name")
    i = i + 1
Next

End Sub

The code overall is the exact same, just referencing a different tab and added more fields to pull out. The change I want to point out is to the for loop itself. The beginning of the for loop now starts by referencing the overall object that contains the array. This is referred to as the “root” of the JSON and you’ll see it if you’re querying a REST API for JSON data. This moves the for each loop inside the “data” level of the JSON and will now loop through all objects in the highest-level array. Had I left this out, the loop would only occur once as the JSON is all contained within a single object at its top level.

The second piece I want to point out is the lines for address and company. These are both objects contained within the parent object. So, in order for me to reach to value I want, I have to reference both keys to get the specific value I need. Lastly, I want to call out that you do not need to write every value from the returned JSON to the sheet. I have skipped over several fields to get the end result I desired and it does not affect my code results, which coincidently look like this:

import json to excel

I hope this brief explanation of how to import JSON to Excel was useful for you! Please let me know if it was helpful or if you have any questions in the comments below. Also, if you want to download the file with the example JSON and VBA code, you can do so here if you’re a free subscriber to the site. It’s free, easy, and only takes a moment to sign up.

Cheers!

R

Tags:
, ,
12 Comments
  • Bertrand CAMBORDE
    Posted at 02:40h, 11 December

    Good morning. First thanks a lot for your post. I am trying the first example on excel for Mac and don’t succeed to get your code up and running. First I had to import the Bas file manually because of excel for mac 2016 not accepting the import of .bas file and I also had to import a dictionary.cls class module manually since once again there is no Microsoft Scrpting runtime reference on Mac. I had to make changes to these codes since it was not working properly (basically commenting out some parts) so not sure if my issue is coming from there or somewhere else. I end up with an execution error 438 on the first loop of for each item in JsonObject saying that this property or method is not supported for item I guess. I have some print screens I can provide if necessary. If you could help me there that would be great. I looked at the local variables and don’t see where the issue is coming from. Thanks in advance for your help

    • Ryan Clouse
      Posted at 17:39h, 11 December

      Hi Bertrand, unfortunately the VBA-JSON library will not work on a mac version of excel. If you need to transform some JSON there are some links you can google that will convert a JSON string to a CSV file for you and you can then import that into your version of Excel, but I do not believe you’ll be able to use the methods I outline above on a mac.

  • Pingback:Parse JSON Using VSTO For Excel | Excelerator Solutions
    Posted at 04:35h, 17 January

    […] Excel Ninjas! My article on using VBA to import JSON into Excel has been one of my most popular. As a follow up to this I wanted to demonstrate how to Parse JSON […]

  • monchai pon
    Posted at 09:22h, 15 March

    i have data like this
    ” “quotes”:{
    “2011-01-01”:{
    “USDGBP”:0.642344,
    “USDEUR”:0.747736,
    “USDJPY”:81.112689,
    “USDAUD”:0.980253,
    “USDCAD”:0.997228,
    “USDCHF”:0.933819,
    “USDNZD”:1.284561,
    “USDUSD”:1
    },
    “2011-01-02”:{
    “USDGBP”:0.642344,
    “USDEUR”:0.747736,
    “USDJPY”:81.112689,
    “USDAUD”:0.980253,
    “USDCAD”:0.997228,
    “USDCHF”:0.933819,
    “USDNZD”:1.284561,
    “USDUSD”:1
    },
    “2011-01-03”:{
    “USDGBP”:0.645641,
    “USDEUR”:0.748624,
    “USDJPY”:81.574874,
    “USDAUD”:0.98178,
    “USDCAD”:0.991898,
    “USDCHF”:0.933549,
    “USDNZD”:1.289685,
    “USDUSD”:1
    }
    }
    }

    how can i apply for it.

    • Ryan Clouse
      Posted at 19:31h, 16 March

      Hi Monchai – can you post some sample code? You should be able to follow along in the tutorial and access your parsed json with keys like (“quotes”)(“2011-01-03”) to access the last one. The string you posted also is not formatted as correct JSON so perhaps that’s the error?

  • Tyler Rose
    Posted at 06:39h, 16 March

    Quick question: I can access a nested key value pair with the syntax of item(“address”)(“street”) as from your example, but I need to get access with a variable and some values will be nested and others aren’t. For example, I want to access it with a variable like item(variable1) where I could define the “variable1” as “name” or “address/street” and pull a value.Is this possible? I was able to do something similar with an XML document, but JSON is giving me trouble.

    • Ryan Clouse
      Posted at 19:28h, 16 March

      Hi Tyler – you should be able to do this by just passing in the variable that is representing your dictionary key(s). What type of variable are you storing the dictionary key as? You’ll probably need to make sure it is of variant type. Do you have some sample code of what you’ve tried to get working?

  • Dean Miller
    Posted at 17:39h, 21 March

    Hi Ryan, I was hoping you could possibly help.

    With the above example, what would be the correct method to pull the “lat” and “lng” from the “geo” item?

    I assume it would be the following:
    ws.Cells(i, 1) = item(“address”)(“geo”)(“lat”)
    ws.Cells(i, 2) = item(“address”)(“geo”)(“lng”)

    But I can’t seem to get this to work, any ideas?

    Thanks,

    • Ryan Clouse
      Posted at 17:48h, 21 March

      Hi Dean,

      You assume correct. I just pulled down the test file and tested and was able to successfully write the value to excel – can you post your code and and error message you are getting? That would help me understand why it may not be working for you.

      Cheers,
      Ryan

      • Dean Miller
        Posted at 09:23h, 22 March

        I’ve realised the data I’m using is slightly different to your example.
        Where you have the “lat” & “lng” as additional items in your JSON, in the set I’m working with, they are stored as a list, encased is square brackets

        “geo”: [{ “lat”: “-37.3159”, “lng”: “81.1496” }] instead of “geo”: { “lat”: “-37.3159”, “lng”: “81.1496” }

        Is there a simpler way to extract these or would that list need to be parsed again?

        • Ryan Clouse
          Posted at 13:55h, 22 March

          Ahh, yes when you have an array you’ll need to iterate it again. The easiest way is probably to iterate over the “geo” array. So if the example I have above were an array, when I reached the “geo” array I would add another loop like “For Each geo in item(“address”)(“geo”)”. I could then access the geo objects by referencing geo(“lat”) and geo(“lng”).

          Alternatively (and I haven’t tested this) you might be able to access by referencing the array’s index. So, you might be able to access it by referencing item(“address”)(“geo”)(0) for lat and item(“address”)(“geo”)(1) for lng.

          Let me know if either of those solutions work for you.

          Cheers!
          Ryan

  • J Manners
    Posted at 16:12h, 17 April

    I’m aware that this may be cutting in on these wonderful ideas, however going on what Dean is talking about. I too had the same problem with the JSON would start off as a new array.. To solve my problem I did something like the below.
    json parse would be;
    {“jsonrpc”:”2.0″,”result”:[{“groupid”:”15″,”name”:”TEST NAME”,”internal”:”0″,”flags”:”0″,”hosts”:[{“hostid”:”10255″,”name”:”TESTING SERVER ONE”}]}],”id”:1}

    The code I used that worked for me:
    Using the advance code above as reference 😉

    Sub GetZabbix()

    Dim ws As Worksheet
    Dim strJSON As String
    Dim strResp As String
    Dim jsonText As String
    Dim httpReq As New WinHttpRequest
    Dim strURL As String
    Dim jsonObject As Object, item As Object
    Dim i As Long
    Dim a As Long ‘ ADDED THIS IN FOR IN LOOP
    Dim grpHost As Object ‘ ADDED THIS IN FOR PARSING RESULTS:HOSTS

    Set ws = Worksheets(“API Group Host”)

    strJSON = “{“”jsonrpc””: “”2.0″”,””method””: “”hostgroup.get””,””params””:{“”filter””:{“”groupid””:””15″”},””selectHosts””:[“”name””]},””id””:1,””auth””: “”KEY FROM SERVER””}”
    strURL = “URL ADDRESS TO THE API”

    httpReq.Option(4) = 13056 ‘
    httpReq.Open “POST”, strURL, False
    httpReq.SetCredentials “YOUR USER ID”, “PASSWORD”, 0
    httpReq.SetRequestHeader “Content-Type”, “application/json-rpc”
    httpReq.SetRequestHeader “User-Agent”, “Mozilla/4.0 (compatible; MSIE 6.0; Windows NT 5.0)”
    httpReq.Send strJSON
    strResp = httpReq.ResponseText
    ws.Cells(20, 1) = strResp
    ‘jsonText = ws.Cells(20, 1)

    Set jsonObject = JsonConverter.ParseJson(strResp)
    i = 2
    a = 4

    ws.Cells(1, 1) = “Group ID”
    ws.Cells(1, 2) = “Group Name”
    ws.Cells(3, 1) = “Host ID”
    ws.Cells(3, 2) = “Host Name”

    For Each item In jsonObject(“result”)
    ws.Cells(i, 1) = item(“groupid”)
    ws.Cells(i, 2) = item(“name”)
    i = i + 1
    For Each grpHost In item(“hosts”)
    ws.Cells(a, 1) = grpHost(“hostid”)
    ws.Cells(a, 2) = grpHost(“name”)
    a = a + 1
    Next
    Next

    Set httpReq = Nothing

    End Sub

    *************
    Hope this helps someone out there..

    cheers,
    J

Post A Comment
Help-Desk