How to get last element of a JSON object in VBA

mintz

Board Regular
Joined
Aug 5, 2015
Messages
117
Code:
{
  "data": {
    "trackings": [
      {
        "tracking_number": "3A5V198427201",
        "shipment_pickup_date": "2016-10-31T23:49:00",
        "tag": "InTransit",
        "title": "3531",
        "checkpoints": [
          {
            "created_at": "2016-11-01T16:09:23+00:00",
            "message": "The electrolic infomation has been received ."
          },
          {
            "created_at": "2016-11-14T17:54:14+00:00",
            "message": "Shipment Ready For Transit."
          },
          {
            "created_at": "2016-11-14T17:54:14+00:00",
            "message": "Shipment Depart From Hub Scan."
          },
          {
            "created_at": "2016-11-15T06:38:28+00:00",
            "message": "A UPS shipping label has been created"
          }
        ]
      }
    ]
  }
}
This is how I get the first checkpoint message:
sMsg = Item("checkpoints")(1)("message")

How do I get the last one? ("A UPS shipping label has been created")
 
Last edited:

Some videos you may like

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type

RickXL

MrExcel MVP
Joined
Sep 9, 2013
Messages
4,314
Hi,

You don't say how you are creating your Json Item so I will have to guess.

I have used JsonConverter in the past. Based on that, you might be able to replace the "1" index number with "Item.Count" (without the quotes).

Regards,
 

mintz

Board Regular
Joined
Aug 5, 2015
Messages
117
Hi,

You don't say how you are creating your Json Item so I will have to guess.

I have used JsonConverter in the past. Based on that, you might be able to replace the "1" index number with "Item.Count" (without the quotes).

Regards,
HiRick

That is a JSON response, I simply put the xmlHttp.response text in a string variable called JsonText

JsonText = xmlHttp.responseText

I have just tried:
sMsg = Item("checkpoints")(Item.Count)
but I get the "9 subscript out of range"
 
Last edited:

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
6,125
That is a JSON response, I simply put the xmlHttp.response text in a string variable called JsonText

JsonText = xmlHttp.responseText
But what are you doing with JsonText? You need to parse/convert it using a VBA JSON parser which puts it into a specific data structure which you can then access to extract the elements you need.
 

mintz

Board Regular
Joined
Aug 5, 2015
Messages
117
But what are you doing with JsonText? You need to parse/convert it using a VBA JSON parser which puts it into a specific data structure which you can then access to extract the elements you need.
I'm parsing it like Rick said using the VBA JSON converter:

Code:
[COLOR=#000080]Set[/COLOR] ParsedJSONDict = JsonConverter.ParseJson(JsonText)
[COLOR=#000080]Set[/COLOR] dicData = ParsedJSONDict("data")
[COLOR=#000080]Set[/COLOR] dicTrack = dicData("trackings")

    [COLOR=#000080]For Each[/COLOR] Item [COLOR=#000080]In [/COLOR]dicTrack
         sMsg = Item("checkpoints")( *last item* )("message") [COLOR=#008000]' get last checkpoint message[/COLOR]
 
Last edited:

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
6,125
Try this:
Code:
    Dim checkpointsColl As Collection
    Set checkpointsColl = dicTrack.item(1).item("checkpoints")
    Debug.Print checkpointsColl.Count
    Debug.Print checkpointsColl.item(1).item("message")  'first checkpoint
    Debug.Print checkpointsColl.item(checkpointsColl.Count).item("message") 'last checkpoint
NB - although it doesn't affect the above code, "trackings" is a Collection, therefore the dicTrack object is a Collection, not a Dictionary as your variable name suggests. Look in the Locals window at run-time and you will see that the last data type of dicTrack is Collection.
 
Last edited:

RickXL

MrExcel MVP
Joined
Sep 9, 2013
Messages
4,314
Could it be that sMsg = Item("checkpoints")(1)("message") is actually returning the second message and that you need to use:
Rich (BB code):
sMsg = Item("checkpoints")(Item.Count - 1)

to return the last message?

Regards,
 

mintz

Board Regular
Joined
Aug 5, 2015
Messages
117
Try this:
Code:
    Dim checkpointsColl As Collection
    Set checkpointsColl = dicTrack.item(1).item("checkpoints")
    Debug.Print checkpointsColl.Count
    Debug.Print checkpointsColl.item(1).item("message")  'first checkpoint
    Debug.Print checkpointsColl.item(checkpointsColl.Count).item("message") 'last checkpoint
NB - although it doesn't affect the above code, "trackings" is a Collection, therefore the dicTrack object is a Collection, not a Dictionary as your variable name suggests. Look in the Locals window at run-time and you will see that the last data type of dicTrack is Collection.
That worked! I was able to access the last message using this:

Code:
[COLOR=#000080]For Each[/COLOR] Item [COLOR=#000080]In [/COLOR]dicTrack
  [COLOR=#000080]Set [/COLOR]checkpointsColl = Item("checkpoints")
  sMsg = Item("checkpoints")(checkpointsColl.Count)("message")
  ' further processing
[COLOR=#000080]Next [/COLOR]Item
PS How do I change "trackings" to a Collection instead of a Dictionary?
 
Last edited:

Forum statistics

Threads
1,089,559
Messages
5,408,958
Members
403,246
Latest member
NateD1

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top