Hi guys, on June 2016, google made some changes around pricing and authentication etc. of its FREE APIs. Distance calculator API was also affected by those changes.

I had written an article long back about how to calculate distance and time taken between two places in Excel VBA using google matrix api. In addition to this article, I had also built a small Excel tool which calculates distance and time taken between two places you type it in. It also has an option to choose your mode of transport. It looks something like below:

Ever since the changes taken place, I am getting many questions from LEM readers that this tool does not work for them anymore.

Therefore, I thought to write this article to explain you more in detail.

In the previous article, i have simply shared a simple VBA code to call Distance matrix API – where no authentication (API Key) was required…

After that changes, the tool I had created and article which I had published were not working. Although, I had replied via comments many time, but I keep getting this question again and again. Therefore, I decided to write this article to answer all the questions at once.

Now, In order to invoke Distance matrix API from google, first you need to get an API key using your google account. For that matter, in order to access any of its API, you need to get an API key to authenticate your API calls.

How to get Google API Key

You can follow the simple steps given here in this article from google – https://developers.google.com/maps/documentation/distance-matrix/get-api-key . Before, you try to call the API from Excel VBA, get this API key for yourself.

As I mentioned previously, it is no longer for free (100%) , you will have some limitations by using your FREE account. more details can be found here

How to use the API key – Excel VBA

As you have learnt in the previous article how to create different parameters before your make a API call, that remains exactly same except the fact that now you need to append &key=YOUR_API_KEY

For example: Here is how a sample URL looks like using API key

https://maps.googleapis.com/maps/api/distancematrix/xml?origins=Amsterdam&destinations=Utrecht&mode=driving&key=YOUR_API_KEY

What is fixed in the Tool

There Two things:

In the code, I have added an exception handling, so that you know what is wrong with the API call. It was my mistake that in my previous article, I did not use any exception handling, therefore it was not clear what exactly the problem is.

Secondly, I have added a placeholder for your API key which you can store it in the config sheet and tool is ready for your own use.

VBA to calculate distance between two places

Here is the VBA code to call Google Distance Matrix API and get distance and time taken :


Function getDistanceAndTimeBetweenTwoPlaces() As Variant
' This function will return an array holding
' distance in meters and duration in seconds
    Dim googleAPIRequest As XMLHTTP60
    Dim domDoc As DOMDocument60
    Dim xmlNodesList As IXMLDOMNodeList
    Dim status As String
    Dim errorMessage As String
    
    Dim response(1) As Variant 'array to hold distance & duration
    
    On Error GoTo err
'API URL is formed in excel sheet config using exccel formula
    urlForDistance = Range("urlForDistance").Value
    
    Set googleAPIRequest = New XMLHTTP60
' invoke the API to get the Distance Matrxi in XML format
    googleAPIRequest.Open "GET", urlForDistance, False
    googleAPIRequest.Send
    
' Get the response XML
    Set domDoc = New DOMDocument60
    domDoc.LoadXML googleAPIRequest.ResponseText
'using xPath first get the status of the API Call
    status = domDoc.SelectSingleNode("//status[1]").nodeTypedValue
    
    errorMessage = domDoc.Text
    If status = "OK" Then
' Using xPath get the distance
        Set xmlNodesList = domDoc.SelectNodes("//distance[1]/*")
        response(0) = xmlNodesList(0).Text
        
' Using xPath get the duration
        Set xmlNodesList = domDoc.SelectNodes("//duration[1]/*")
        response(1) = xmlNodesList(0).Text
        
' Return response with distance and duration in array
        getDistanceAndTimeBetweenTwoPlaces = response
        
' release memory
        Set xmlNodesList = Nothing
    Else
        
        MsgBox errorMessage
        
    End If
err:
    Set domDoc = Nothing
    Set googleAPIRequest = Nothing
End Function

Download the working Distance Calculator Tool

Note:

Before you run this excel sheet, you need to get your API key generated from your google account and put that key in the excel sheet at specified place and then enjoy using it.

Download – FREE Distance Calculator in Excel

cover3d_0-89071700_1484285537__1_

Join over 10, 000+ Excel VBA Enthusiasts & get this FREE e-Book Now!