NOTE: This post was written before Data Explorer was renamed as Power Query. All of the content is still relevant to Power Query.
Don’t you hate it when you get ready to blog about something cool, and then someone comes along and beats you to it? That’s what’s just happened to me – Matt Masson just wrote an excellent blog post on how to do address lookup against a web service here:
http://www.mattmasson.com/2013/03/dynamic-lookups-with-data-explorer/
That’s what I was going to write about in part 2 of this series. I have to say he did a better job than I would have done though, and shows off several cool tricks I hadn’t seen before…
Ah well, so it goes – and anyway there are a few things I was going to say that are still worth saying. If you remember, in Part 1 I showed how to call the Google Distance Matrix API from Data Explorer, but I hard-coded the start and end points in the expression I used. How can you get the start and end points directly from Excel? Well it turns out that Data Explorer can read values direct from Excel tables.
To start with, you need to create some Excel tables to hold the values you want to use. I created two Excel tables called Origin and Destination to hold the two values I needed:
I can then take the value from the first row in the sole column of each table (which are again called Origin and Destination, as you can see) by using
Excel.CurrentWorkbook(){[Name=”Origin”]}[Content]{0}[Origin]
and
Excel.CurrentWorkbook(){[Name=”Destination”]}[Content]{0}[Destination]
Here’s the full source expression with the hard-coded values replaced:
=
Xml.Document(
Web.Contents(
“http://maps.googleapis.com/maps/api/distancematrix/xml”
, [Query = [
origins= Excel.CurrentWorkbook(){[Name=”Origin”]}[Content]{0}[Origin]
, destinations = Excel.CurrentWorkbook(){[Name=”Destination”]}[Content]{0}[Destination]
, mode = “driving”, sensor = “false” ] ]))
Now, you can enter any address in the Origin and Destination tables, click Refresh on the Query as shown in the screenshot below:
And the query will be rerun with the new parameters. Note that it might also be a good idea to URL encode any text that you enter in these tables, using the EncodeURL() Excel function; I haven’t done so here because I’m using UK postcodes, which don’t need URL encoding, as my origins and destinations to make things simple.
It’s also possible to use the results of one query inside another query. Data Explorer allows you to use an Excel table as the source for a query:
And selecting the Destination Excel table as a source gives the following expression:
= Excel.CurrentWorkbook(){[Name=”Destination”]}[Content]
The easy way to use any value from an existing query as the starting point for a new query is to right-click on a cell and select Add As New Query:
Doing this creates a new query with the value you clicked on a source:
Here’s the expression for the only step in the newly-created query:
= Destination{0}[Destination]
Even if this new query isn’t any use on its own, the expression shown here can be used in other queries. Here’s the original web service call adapted to use two other queries as its source:
= Xml.Document(
Web.Contents(
“http://maps.googleapis.com/maps/api/distancematrix/xml”
, [Query = [
origins= Origin{0}[Origin]
, destinations = Destination{0}[Destination]
, mode = “driving”, sensor = “false” ] ]))
However, as Matt shows in his post, this only works if Fast Combine is enabled, otherwise you’ll see an error message.
You can download the sample workbook for this post here.
Your link for the sample workbook is not quite correct.
Sorry David, that’s fixed now.
Thanks!
@Chris – Could you please provide a example of specifying a “API key” in the M Code
Does this post help? https://blog.crossjoin.co.uk/2014/03/26/working-with-web-services-in-power-query/