Calling A Web Service From Data Explorer (Power Query), Part 1

NOTE: This post was written before Data Explorer was renamed as Power Query. All of the content is still relevant to Power Query.

Last week I showed how you could use the WebService() function in Excel 2013 to bring location data into Excel 2013. Since this is a topic I have a particular interest in, this week I’ll show you how to do the same thing all over again but in Data Explorer.

First of all, a simple example. In that previous post I used the Google Distance Matrix API to calculate the distance between two points; for example the following call shows how long it would take me to drive from my home to Buckingham Palace to see the Queen (52 minutes in case you’re wondering):
http://maps.googleapis.com/maps/api/distancematrix/xml?origins=HP66HF&destinations=SW1A1AA&mode=driving&sensor=false

The following post on the Data Explorer forum from James Terwilliger gives some helpful tips on how to consume web services from within Data Explorer:
http://social.msdn.microsoft.com/Forums/en-US/dataexplorer/thread/069b50e3-ab9e-4ee4-99a9-23440fcfc768

…but it’s not altogether straightforward. For example if you paste the link above into the From Web data source, you do get something returned but it’s extremely hard to find any useful data. Instead, I found the following steps worked:

  • First, hit From Web and enter something in the URL box:
    image
  • This gives you a new web query, but you want to discard any auto-generated code in the first step. Instead, paste the following expression:= Xml.Document(
    Web.Contents(“http://maps.googleapis.com/maps/api/distancematrix/xml”
    , [Query = [ origins= “HP66HF”, destinations = “SW1A1AA”, mode = “driving”, sensor = “false” ] ]))

    image

    This uses Web.Contents() to call the web service (as described in that forums reply) with the appropriate parameters. Xml.Document() is then used to interpret the response as an XML document.

  • With this done, it’s quite easy to navigate through the XML by clicking on the Table links in each step to find the useful data:
    image
  • And finally hit Done to surface it the worksheet:
    image

Some thoughts at this point: I don’t like the way the DE formula language is case-sensitive, and I suspect in the long run it will have to be either hidden or replaced with VBA or Excel formula language/DAX if it’s going to be used even by Excel power users. It is very, very powerful though, and luckily the UI is good enough to mean that 99% of users will never need to write DE formula language anyway.

The next question: I’ve hard-coded my origins and destinations in this example, but how can I read these values from the worksheet without my users having to open Data Explorer and edit the query? Tune in for Part 2 to find out!

Importing Data From Multiple Log Files Using Data Explorer (Power Query)

NOTE: This post was written before Data Explorer was renamed as Power Query. All of the content is still relevant to Power Query.

It’s only been two days since the official Preview release of Data Explorer and already the blog posts about it are coming thick and fast. Here are some of the more interesting ones that I’ve seen that show what’s possible with it:
http://sqlblog.com/blogs/jamie_thomson/archive/2013/02/28/traversing-the-facebook-graph-using-data-explorer.aspx
http://www.mattmasson.com/index.php/2013/03/access-the-windows-azure-marketplace-from-data-explorer/
http://community.altiusconsulting.com/best-oscar-winning-film-my-first-data-explorer-adventure/
http://www.spsdemo.com/blog/Lists/Posts/Post.aspx?List=c67861cd-a0d9-4ed8-9d9d-9b29652a516f&ID=371&Web=f74569c2-ae3f-42c6-a3fa-9f099dfaeb7f

Obviously I can’t let everyone else have all the fun, so I thought I’d show how you can use Data Explorer to import data from multiple files, clean it, load it into a single table and then report on it.

First of all, the data. Like all bloggers I have an unhealthy interest in my blog stats, and one of the ways I monitor the hits on this site is using Statcounter. I’m also a bit of a miser, though, so I only use their freebie service and that means that I only get to see stats on the last 500 site visits. How can I analyse this data then? Well, Statcounter allow you to download log data as a csv file, so at about 2:30pm I downloaded one file and at 8:30pm I downloaded another.

Now, the first cool thing to show about Data Explorer is that you can import and merge data from multiple files with the same structure if they’re in the same folder. With both of my files in a folder called Blog Logs, and Excel open, the first thing you need to do is to the Data Explorer tab and hit From File/From Folder:

image

The next step is to enter the name of the folder with the files in in the dialog:

image

With that done, a new Query screen appears with a list of the files in the folder:

image

You then need to hit the icon with the two down arrows and a horizontal line that I’ve highlighted in the screenshot above, next to the Content heading. This then shows the data in the files (obviously I’ve had to scrub out the sensitive data here):

image

You can then use the first row as the column headers:

image

Filter the data so that the row with the second set of column headers is removed (I wonder if there’s a way to do this automatically when importing multiple csv files?) by clicking on the Date and Time column and deselecting the value “Date and Time” as shown:

image

Right-click on each column you don’t want to import (such as IP Address) and selecting Hide:

image

Right-click on the Date and Time column and select Remove Duplicates to remove any records that appear in both log files (I’m assuming that there were no cases where two people hit a page at exactly the same date and time, which of course may not be completely correct):

image

And force the Date and Time column to be treated as a Date/Time type:

image

And bingo, you’re done. Here are all the steps in the import, all of which can be edited, deleted, reordered etc:

image

The data is then loaded into a table in a worksheet (though you can turn that off), and by clicking “Load to data model” in the Query Settings pane you can load the data into the Excel data model:

image

(NB I found some issues with loading date data into the data model and US/European date formats that I’ve reported here, but don’t forget this is beta software so there are bound to be problems like this)

You can build cool Power View reports using this data:

image

Or even explore it on a 3D map with GeoFlow:

image

Fun, isn’t it?

%d bloggers like this: