This blog contains experience gained over the years of implementing (and de-implementing) large scale IT applications/software.

List Your Azure VMs in Excel – Part 3

The third and final part to the trilogy.
I show you how to list your Azure VMs in Excel O365 using Power Query, and this time we enhance the code even further using the Power Query function List.Accumulate, to accumulate the returned list of VMs from each subscription into one big list.

Like an episode of a tacky day-time television show, it’s always worth wasting some words on a recap.
So, in-case you’re not aware, here’s what has happened in this saga so far:

List Your VMs in Excel – part1
The first part of the trilogy, showed how to create a new Power Query in Excel O365, and how to enter the code, which generated a basic VM list from Azure.

List Your VMs in Excel – part2
The second part enhanced the code slightly, parameterising more of the text strings.
It also introduced the ability to get the powerState of each VM from Azure, allowing you to see in Excel, which VMs were running and which were deallocated.

By applying the code changes from this post, you will no longer need multiple Power Query queries, going from 1 per Azure subscription, to just 1 query for all subscriptions.

What’s New?

As mentioned, the code now includes the use of the Power Query “List.Accumulate” function to combine the lists of VMs from multiple subscriptions.

I’ve never really use Power Query before, so even I had no idea how to loop on a list of values and execute a function on each loop. After a bit of searching I found that the List.Accumulate function did exactly what I needed it to do, with minimal coding needed.

Here’s a pretty comprehensive description of how List.Accumulate works: https://datachant.com/2016/06/02/power-query-list-accumulate-unleashed/

What you will notice is that our code has the following properties:
subscriptions = Our defined list of Azure subscriptions.
{} = Our blank list as a seed.
List.Combine = Is executed for each entry in our subscriptions list.

List.Accumulate(subscriptions, 
                {},
                (state,current)=>
                              List.Combine({state,FnGeneratedVMList(current)}))

We define the subscriptions list right at the start of the code:

subscriptions = {"[your subscription1]","[your subscription2]"} as list, 

To make our code work with the List.Accumulate, we have changed the “GeneratedVMList” variable contents, to be a function, instead of a string:

// FnGeneratedVMList pages through the subscription and gets the VM lists. 
FnGeneratedVMList = (subscription as text) as list => 
 List.Generate( ()=>[i=0, 
  res = FnGetOnePage(endPoint & "/subscriptions/" & subscription & "/providers/Microsoft.Compute/virtualMachines?api-version=" & apiVersion)], 
  each [i]null, 
  each [i=[i]+1, 
  res = FnGetOnePage([res][Next])], 
  each [res][Data]),

The main benefit of the function is that it can now be passed a parameter “subscription“, which is used to adjust the URI to the Azure API for the correct subscription.

The End Result

The end result of our changes is the following code:

let 
 iterations = 10 as number, 
 // Max Number of Pages of VMs. 
 endPoint = "https://management.azure.com" as text, 
 subscriptions = {"[your subscription1]","[your subscription2]"} as list, 
 apiVersion = "2019-07-01" as text,
 
// FnGetOnePage is the function that performs an import of single page. 
// The page consists of a record with the data and the URL in the 
// fields data and next. Other Web APIs hold the data and cursor in different formats 
// but the principle is the same. 
FnGetOnePage = (url) as record => 
 let Source = Json.Document(Web.Contents(url)), 
 data = try Source[value] otherwise null, 
 next = try Source[nextLink] otherwise null, 
 res = [Data=data, Next=next] 
in 
 res,
 
// FnGetVMdisplayStatus gets the instanceView object for the passed VM ID 
// then parses out the displayStatus from one of two possible locations. 
FnGetVMdisplayStatus = (idURI) as text => 
 let Source = Json.Document(Web.Contents(endPoint & idURI & "/instanceView?api-version=" & apiVersion)), 
 statuses = Source[statuses], 
 vmDisplayStatus1 = try statuses{1}[displayStatus] otherwise "", 
 vmDisplayStatus2 = try statuses{2}[displayStatus] otherwise "", 
 vmDisplayStatus = vmDisplayStatus1 & vmDisplayStatus2 
in
 vmDisplayStatus,

// FnGeneratedVMList pages through the subscription and gets the VM lists. 
FnGeneratedVMList = (subscription as text) as list => 
 List.Generate( ()=>[i=0, 
  res = FnGetOnePage(endPoint & "/subscriptions/" & subscription & "/providers/Microsoft.Compute/virtualMachines?api-version=" & apiVersion)], 
  each [i]null, 
  each [i=[i]+1, 
  res = FnGetOnePage([res][Next])], 
  each [res][Data]),

// SubscriptionsVMList combines the returned lists using the Accumulator. 
SubscriptionsVMList = 
 List.Accumulate(subscriptions, {},(state,current)=>List.Combine({state,FnGeneratedVMList(current)})),
 
#"VMListTable" = Table.FromList(SubscriptionsVMList, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 
#"Expanded-VMListTable-Column1" = Table.ExpandListColumn(#"VMListTable", "Column1"), 
#"VMdetail-list" = Table.ExpandRecordColumn(#"Expanded-VMListTable-Column1", "Column1", {"name","id"}), 
#"VMdetail-list-with-displayStatus" = Table.AddColumn(#"VMdetail-list", "displayStatus", try each FnGetVMdisplayStatus([id]) otherwise "??") 
in 
#"VMdetail-list-with-displayStatus"

You will need to adjust [your subscription1] and [your subscription2] with your subscriptions, adding any additional subscriptions in the same format.

If you only have one subscription, you can still use this code, just remove one of the items from the subscriptions list, like so:

subscriptions = {"[your subscription1]"} as list,

Summary

Hopefully you can see how you can enhance the code slightly to include more VM details if you need them.
As an example, this line here can be adjusted to include additional columns as well as “name” and “id” (for example: “location“), as per the VM list API call (see the first part of this trilogy for more detail):

#"VMdetail-list" = Table.ExpandRecordColumn(#"Expanded-VMListTable-Column1", "Column1", {"name","id"}), 

You can now enjoy your data in Excel.

Update 23-June: Due to popular demand, here is how the above code can be changed to include the “location” and “vmSize” fields, which will depict the location and series/size of the VM.
We make a small change to the last few lines like so:

#"VMListTable" = Table.FromList(SubscriptionsVMList, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 
"Expanded-VMListTable-Column1" = Table.ExpandListColumn(#"VMListTable", "Column1"),
#"VMdetail-list" = Table.ExpandRecordColumn(#"Expanded-VMListTable-Column1", "Column1", {"name","id", "location", "properties"}),
#"VMdetail-list-properties" = Table.ExpandRecordColumn(#"VMdetail-list", "properties", {"hardwareProfile"}, {"hardwareProfile"}),
#"VMdetail-list-properties-hardwareProfile" = Table.ExpandRecordColumn(#"VMdetail-list-properties", "hardwareProfile", {"vmSize"}, {"vmSize"}),
#"VMdetail-list-with-displayStatus" = Table.AddColumn(#"VMdetail-list-properties-hardwareProfile", "displayStatus", try each FnGetVMdisplayStatus([id]) otherwise "??"),
in 
#"VMdetail-list-with-displayStatus"


One thought on

Add Your Comment

* Indicates Required Field

Your email address will not be published.

*