Calculate Travel Time and Distance using Google Maps API

Falko26

Board Regular
Joined
Oct 13, 2021
Messages
89
Office Version
  1. 365
Platform
  1. Windows
Hey Team,

Has anyone used the Google Maps API with VBA to get Travel Distance and Time? For some reason I am getting it to work with Travel Time but I can only get some of my Travel distances to report correctly. My VBA Function is giving me an #VALUE error.

For some reason my formula will not work for Travel Distance. When using the Test HTTP It works and I get Travel Time and Distance but in Excel only Travel Time works 100% of the time while Travel Distance only works 50% of the Time.
1697494344750.png


Google Maps API:

Code:
VBA Code:
Function TRAVELTIME(origin, destination, apikey)
    Dim strUrl As String
    strUrl = "https://maps.googleapis.com/maps/api/directions/json?origin=" & origin & "&destination=" & destination & "&key=" & apikey

    Set httpReq = CreateObject("MSXML2.XMLHTTP")
    With httpReq
        .Open "GET", strUrl, False
        .Send
    End With
   
    Dim Response As String
    Response = httpReq.ResponseText
   
    Dim parsed As Dictionary
    Set parsed = JsonConverter.ParseJson(Response)
    Dim seconds As Integer
   
    For Each leg In parsed("routes")(1)("legs")
        seconds = seconds + leg("duration")("value")
    Next leg
   
    TRAVELTIME = seconds
   
End Function

Function TRAVELDISTANCE(origin, destination, apikey)
    Dim strUrl As String
    strUrl = "https://maps.googleapis.com/maps/api/directions/json?origin=" & origin & "&destination=" & destination & "&key=" & apikey

    Set httpReq = CreateObject("MSXML2.XMLHTTP")
    With httpReq
        .Open "GET", strUrl, False
        .Send
    End With
   
    Dim Response As String
    Response = httpReq.ResponseText
   
    Dim parsed As Dictionary
    Set parsed = JsonConverter.ParseJson(Response)
    Dim meters As Integer
   
    For Each leg In parsed("routes")(1)("legs")
        meters = meters + leg("distance")("value")
    Next leg
   
    TRAVELDISTANCE = meters
End Function
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
I can only get some of my Travel distances to report correctly. My VBA Function is giving me an #VALUE error.

Because Dim meters As Integer has a maximum value of 32,767. Change it to Dim meters As Long and the TRAVELDISTANCE function should work for all distances.

I would also change Dim seconds As Integer to Dim seconds As Long in the TRAVELTIME function.
 
Upvote 0
Solution
Because Dim meters As Integer has a maximum value of 32,767. Change it to Dim meters As Long and the TRAVELDISTANCE function should work for all distances.

I would also change Dim seconds As Integer to Dim seconds As Long in the TRAVELTIME function.
Thanks John!
I did not know the difference there between Integer and Long but that seems to have worked!!
 
Upvote 0
Thanks John!
I did not know the difference there between Integer and Long but that seems to have worked!!
VBA best practice is to use Long rather than Integer and Double rather than Single. Behind the scenes, VBA converts the smaller variable type to the larger, does any calcs, then converts back. This invalidates the conventional wisdom that smaller variables use less memory and calculate faster.
 
Upvote 0

Forum statistics

Threads
1,215,077
Messages
6,122,991
Members
449,094
Latest member
masterms

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top