Skip to content

Commit

Permalink
Added M query for summary/data date + restructed a bit
Browse files Browse the repository at this point in the history
  • Loading branch information
tvuylsteke committed Jan 28, 2017
1 parent ccf656c commit 1a513a9
Show file tree
Hide file tree
Showing 17 changed files with 210 additions and 17 deletions.
File renamed without changes.
File renamed without changes.
Original file line number Diff line number Diff line change
Expand Up @@ -84,7 +84,7 @@ Now that we have configured the automated download of the usage data it's to get
* You'll see a yellow bar asking you to specify credentials to connect. Click Edit Credentials.
* Copy paste the **storage account access key** you copied earlier
* Now it should refresh and load your data
* Provide a name for the query: e.g. Azure Usage Data
* Provide a name for the query: "Usage Detail"
* Close the query window and click yes when asked to apply query changes

### Report
Expand Down
File renamed without changes.
19 changes: 19 additions & 0 deletions Details - V2 - One API Call/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
# Visualize Azure EA Usage Data with Power BI: One API Call

## Power BI Desktop

With the EA details (enrollment number and API key) we can start setting up the data sources within Power Bi. For this approach we'll communicate directly with the EA API. This approach is rather simple as we only need one data source and no intermediate components. The only downside is that it will retrieve all data and then filter. The consequence is that refreshing might take quite some time. When authoring the report that can be seen as a nuisance. Once uploaded to Power Bi online this should be less important.

### Set Up The Data Source

* Open Power BI Desktop.
* Click Get Data and choose **Blank Query**. A second window should open up.
* Choose Advanced Editor and copy paste the code from the [PowerBI-EA-UsageData-v2.m](/PowerBI-EA-UsageData-v2.m) file.
* Replace the **EA Enrollment Number** on the 2nd line (1234567 in the sample code)
* The line that starts with #"Setup: Filtered Rows" (line 9) controls how many months are made available. The sample currently takes 12 months into account, including the current month.
* Click done in the advanced editor
* You'll see a yellow bar asking you to specify credentials to connect. Click Edit Credentials.
* Copy paste the **EA API Key** you copied earlier
* Now it should refresh and load your data
* Provide a name for the query: e.g. Azure Usage Data
* Close the query window and click yes when asked to apply query changes
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
(YearMonth as text) as table =>
let
report = Table.FromColumns({Lines.FromBinary(Binary.Buffer(AzureEnterprise.Contents("https://ea.azure.com/rest/1234567/usage-report", [month=YearMonth, type="detail", fmt="Csv"])),null,null,1252)}),
skips = Table.Skip(report, 2),
split = Table.SplitColumn(skips, "Column1", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv)),
promoted = Table.PromoteHeaders(split)
in
promoted
56 changes: 56 additions & 0 deletions Details - V3 - Multiple API Calls/PowerBI-EA-UsageData-v3.m
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
let
#"Date Range List" = List.Generate(()=>14, each _ > 0,each _ -1 , each Date.AddMonths(DateTime.LocalNow(),-_+1)),
#"Date Range List: formatting" = List.Transform(#"Date Range List", each Text.From(Date.Year(_))&"-"&Text.PadStart(Text.From(Date.Month(_)),2,"0")),
#"Converted to Table" = Table.FromList(#"Date Range List: formatting", Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Invoked Custom Function" = Table.AddColumn(#"Converted to Table", "Data", each getEAUsageData([Column1])),
#"Renamed Columns" = Table.RenameColumns(#"Invoked Custom Function",{{"Column1", "Name"}}),
//we're going to store the data column in a temporary variable
#"Data: Content" = Table.Column(#"Renamed Columns", "Data"),
//we're looping over all tables to get a list of all columnnames
#"Data: ColumNames" = List.Distinct(List.Combine(List.Transform(#"Data: Content",
each Table.ColumnNames(_)))),
//using the list of columnnames we can now expand the data
#"Data: Expanded Data" = Table.ExpandTableColumn(#"Renamed Columns", "Data",#"Data: ColumNames",#"Data: ColumNames"),
//the line below is an alternative approach. This is the code that is generated by clicking the expand button on a column.
//#"Data: Expanded Data" = Table.ExpandTableColumn(#"Setup: Filtered Rows", "Data", {"AccountOwnerId", "Account Name", "ServiceAdministratorId", "SubscriptionId", "SubscriptionGuid", "Subscription Name", "Date", "Month", "Day", "Year", "Product", "Meter ID", "Meter Category", "Meter Sub-Category", "Meter Region", "Meter Name", "Consumed Quantity", "ResourceRate", "ExtendedCost", "Resource Location", "Consumed Service", "Instance ID", "ServiceInfo1", "ServiceInfo2", "AdditionalInfo", "Tags", "Store Service Identifier", "Department Name", "Cost Center", "Unit Of Measure", "Resource Group", ""}, {"AccountOwnerId", "Account Name", "ServiceAdministratorId", "SubscriptionId", "SubscriptionGuid", "Subscription Name", "Date", "Month", "Day", "Year", "Product", "Meter ID", "Meter Category", "Meter Sub-Category", "Meter Region", "Meter Name", "Consumed Quantity", "ResourceRate", "ExtendedCost", "Resource Location", "Consumed Service", "Instance ID", "ServiceInfo1", "ServiceInfo2", "AdditionalInfo", "Tags", "Store Service Identifier", "Department Name", "Cost Center", "Unit Of Measure", "Resource Group", ""}),
//we only need to change the type for non-text columns
#"Setup: Changed Type Localized" = Table.TransformColumnTypes(#"Data: Expanded Data",{{"SubscriptionId", Int64.Type}, {"Month", Int64.Type}, {"Day", Int64.Type}, {"Year", Int64.Type}, {"Consumed Quantity", type number}, {"ResourceRate", type number},{"Date", type date},{"ExtendedCost", type number}},"en-US"),
// in some cases we end up with some empty rows, we only want to keep the rows with actual data (e.g. subscription guid being present)
#"Setup: Filter Empty Rows" = Table.SelectRows(#"Setup: Changed Type Localized", each [SubscriptionGuid] <> null),
//further down we'll expand the Tags column. In order to keep the original column we'll take a copy of it first
#"Tags: Duplicated Column" = Table.DuplicateColumn(#"Setup: Filter Empty Rows", "Tags", "Tags - Copy"),
//We need to pouplate the empty json tag {} for values that are blank
#"Tags: Replace Empty Value" = Table.ReplaceValue(#"Tags: Duplicated Column","","{}",Replacer.ReplaceValue,{"Tags - Copy"}),
//sometimes tags might have different casings due to erroneous input (e.g. Environment and environment). Here we convert them to Proper casing
#"Tags: Capitalized Each Word" = Table.TransformColumns(#"Tags: Replace Empty Value",{{"Tags - Copy", Text.Proper}}),
//convert the content of the Tags column to JSON records
#"Tags: in JSON" = Table.TransformColumns(#"Tags: Capitalized Each Word",{{"Tags - Copy", Json.Document}}),
//The next steps will determine a list of columns that need to be added and populated
//the idea is to have a column for each tag key type
//take the Tags column in a temp list variable
//source of inspiration: https://blog.crossjoin.co.uk/2014/05/21/expanding-all-columns-in-a-table-in-power-query/
#"Tags: Content" = Table.Column(#"Tags: in JSON", "Tags - Copy"),
//for each of the Tags: take the fieldnames (key names) and add them to a list while removing duplicates
#"Tags: FieldNames" = List.Distinct(List.Combine(List.Transform(#"Tags: Content",
each Record.FieldNames(_)))),
//sometimes EA Usage Data contains a lot of hidden tags. For now I don't know where they are comming from
//this results in a massive amount of columns. For now I'm just filtering them
//Examples: "Hidden-Related:/Subscription/…" or "Hidden-Devtestlabs-Labid..."
#"Tags: Filtered FieldNames" = List.Select(#"Tags: FieldNames", each not Text.StartsWith(_,"Hidden-")),
//this is the list of the actual column names. We're prepending Tag.'
#"Tags: New Column Names" = List.Transform(#"Tags: Filtered FieldNames", each "Tag." & _),
//expand the JSON records using the fieldnames (keys) to new column names list mapping
#"Tags: Expanded" = Table.ExpandRecordColumn(#"Tags: in JSON", "Tags - Copy", #"Tags: Filtered FieldNames",#"Tags: New Column Names"),
//create a column with the consumption date (instead of 3 separate columns)
#"Consumption Date: Added Column" = Table.AddColumn(#"Tags: Expanded", "ConsumptionDate", each Text.From([Month])&"/"&Text.From([Day])&"/"&Text.From([Year])),
#"Consumption Date: Change to Date Type" = Table.TransformColumnTypes(#"Consumption Date: Added Column",{{"ConsumptionDate", type date}},"en-US"),
//create a column with the amount of days ago the usage happened
#"Date Difference: Added Column" = Table.AddColumn(#"Consumption Date: Change to Date Type", "DateDifference", each Duration.Days(Duration.From(DateTime.Date(DateTime.LocalNow())- [ConsumptionDate]))),
#"Date Difference: Changed to Number Type" = Table.TransformColumnTypes(#"Date Difference: Added Column",{{"DateDifference", type number}}),
//create a friendly name for resource (as an alternative to the instance ID which is quite long)
#"Resource Name: Duplicate Instance ID" = Table.DuplicateColumn(#"Date Difference: Changed to Number Type", "Instance ID", "Instance ID-TEMP"),
#"Resource Name: Split Column" = Table.SplitColumn(#"Resource Name: Duplicate Instance ID","Instance ID-TEMP",Splitter.SplitTextByEachDelimiter({"/"}, QuoteStyle.Csv, true),{"Instance ID.1", "Instance ID.2"}),
#"Resource Name: Construct Column" = Table.AddColumn(#"Resource Name: Split Column", "Resource Name", each if [Instance ID.2] = null then [Instance ID.1] else [Instance ID.2] ),
#"Cleanup: Removed Undesired Columns" = Table.RemoveColumns(#"Resource Name: Construct Column",{"Instance ID.1", "Instance ID.2", "AccountOwnerId", "Account Name", "ServiceAdministratorId"})
in
#"Cleanup: Removed Undesired Columns"
30 changes: 30 additions & 0 deletions Details - V3 - Multiple API Calls/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
# Visualize Azure EA Usage Data with Power BI: Multiple API Calls

## Power BI Desktop

With the EA details we can start setting up the data sources within Power Bi. For this approach we'll need to data sources: a function and a data set. This approach should be more performant as we'll only retrieve the months we are interested. The V2 approach first retrieves all available data and then only considers the months we care about. Once the report is upload to Power BI Online it might not really matter. But for editting this should be a huge improvement.

### Set Up Function

* Open Power BI Desktop.
* Click Get Data and choose **Blank Query**. A second window should open up.
* Choose Advanced Editor and copy paste the code from the [PowerBI-EA-UsageData-function-v3.m](/PowerBI-EA-UsageData-function-v3.m) file.
* Replace the **EA Enrollment Number** on the 3th line (1234567 in the sample code)
* Click done in the advanced editor
* Name the query: "getEAUsageData"

### Set Up The Data Source

* Click Get Data and choose **Blank Query**. A second window should open up.
* Choose Advanced Editor and copy paste the code from the [PowerBI-EA-UsageData-v3.m](/PowerBI-EA-UsageData-v3.m) file. *
* The line that starts with #"Date Range List" (line 2) controls how many months are made available. The sample currently takes 14 months into account, including the current month.
* Click done in the advanced editor
* You'll see a yellow bar asking you to specify credentials to connect. Click Edit Credentials.
* Copy paste the **EA API Key** you copied earlier
* Now it should refresh and load your data
* Provide a name for the query: "Usage Detail"
* Close the query window and click yes when asked to apply query changes

### Report

The instructions and tips for visualization are on the homepage of this project.
Binary file added IMG/PowerBI-refresh.PNG
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Binary file added IMG/PowerBI-summary-setup.PNG
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Binary file added IMG/PowerBI-summary.PNG
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
25 changes: 9 additions & 16 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ Yep, that's JSON. The data in that format is basically useless within Power BI o

![Alt text](/IMG/PowerBIDesktop.png?raw=true)

The script on this repository does that. The V1 folder contains my previous attempt at tackling this challenge. While it's working fine it requires additional services like Azure Automation and an Azure Storage Account. Eventually I found out I could get rid of all this and just use the following components:
The scripts on this repository does that. The "Details - V1" folder contains my first attempt at tackling this challenge. While it's working fine it requires additional services like Azure Automation and an Azure Storage Account. Eventually I found out I could get rid of all this and just use the following components:

* Azure EA Rest API: allows you to download the usage data
* Power BI Desktop: allows you to do all kinds of funky things with the data before making it available to your reports
Expand All @@ -31,21 +31,10 @@ Log in to the Azure EA Portal (https://ea.azure.com) and get your:

## Power BI Desktop

Now that we have configured the automated download of the usage data it's to get the Power BI part up and running. Using the M query language we will read all CSV files we find in the container and shape the data so that it can be used within our reports.
Depending on the size of your environment you can choose which appraoch to follow:

### Set Up The Data Source

* Open Power BI Desktop.
* Click Get Data and choose **Blank Query**. A second window should open up.
* Choose Advanced Editor and copy paste the code from the [PowerBI-EA-UsageData-v2.m](/PowerBI-EA-UsageData-v2.m) file.
* Replace the **EA Enrollment Number** on the 2nd line (1234567 in the sample code)
* The line that starts with #"Setup: Filtered Rows" (line 9) controls how many months are made available. The sample currently takes 12 months into account, including the current month.
* Click done in the advanced editor
* You'll see a yellow bar asking you to specify credentials to connect. Click Edit Credentials.
* Copy paste the **EA API Key** you copied earlier
* Now it should refresh and load your data
* Provide a name for the query: e.g. Azure Usage Data
* Close the query window and click yes when asked to apply query changes
* Simple filtering: [PowerBI-EA-UsageData-v2](/Details - V2 - One API Call/README.md)
* Filter before getting data: [PowerBI-EA-UsageData-v3](/Details - V3 - Multiple API Calls/README.md)

### Report

Expand Down Expand Up @@ -78,4 +67,8 @@ Some general notes and thoughts:

[2017/01/05] I've added a filter for the tags that are expanded. Some people mentioned that somewhere along the line tags are added that are not visible within Azure. These all start with "Hidden-" The following line removes these and prevents the columns being added.

"Tags: Filtered FieldNames" = List.Select(#"Tags: FieldNames", each not Text.StartsWith(_,"Hidden-")),
"Tags: Filtered FieldNames" = List.Select(#"Tags: FieldNames", each not Text.StartsWith(_,"Hidden-")),

[2017/01/27] I've moved the PowerBI-EA-UsageData-v2 to a separate folder and added the V3 one. The V3 one is very similar to the V2 one however this one uses a function. The advantage is that the function only retrieves the data that you ask for.

[2017/01/28] I've added a script to get the EA summary data and a data source to show the last date of the data in the retrieved set.
8 changes: 8 additions & 0 deletions Refresh Date - V1/PowerBI-EA-DataDate-v1.m
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
let
Source = #"Usage Detail",
#"Calculated Latest" = List.Max(Source[ConsumptionDate]),
#"Converted to Table" = #table(1, {{#"Calculated Latest"}}),
#"Changed Type" = Table.TransformColumnTypes(#"Converted to Table",{{"Column1", type date}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}})
in
#"Renamed Columns"
36 changes: 36 additions & 0 deletions Refresh Date - V1/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
# Visualize Azure EA Usage Data with Power BI: Data Date

One of the questions you often see in Power BI fora is how to display a date on a report showing when the last refresh happened. To be honest, with the EA dataset I'm more interested in knowing what the most recent date is in the returned dataset. Using the instructions below you'll be able to do just that. This is how the visual will look like:

![Alt text](../IMG/PowerBI-refresh.png?raw=true)

## Power BI Desktop

This configuration happens within Power BI Desktop

### Set Up Data Source

* Open Power BI Desktop.
* Click Get Data and choose **Blank Query**. A second window should open up.
* Choose Advanced Editor and copy paste the code from the [PowerBI-EA-DataDate.m](/PowerBI-EA-DataDate.m) file.
* Replace the **EA Enrollment Number** on the 3th line (1234567 in the sample code)
* Click done in the advanced editor
* Name the query: "Most Recent Data Date"

### Set Up The Measure

This is where I'm lacking some Power BI knowledge. While the data source shows the correct date, I cannot get the card visual to display it correctly. For some reason the visual is only willing to apply the Summarize Count or Count Distinct. As a workaround, or mabye a requirement, I added a measure.

* Close the Query Editor
* Select the "Most Recent Data Date" data source
* Click New Measure
* Copy paste this in the function bar: Most Recent Data Date = FORMAT(LASTDATE('Most Recent Data Date'[Date]),"mmm dd, yyyy")

### Set Up Visualisation

In the last step we'll add the card to a report so that we can display the date.

* Go to the Report View
* Click the page where you want to add the date
* Click the Card visual
* Drag and drop the "Most Recent Data Date" measure from the "Most Recent Data Date" datasource to the Fields value
13 changes: 13 additions & 0 deletions Summary - V1/PowerBI-EA-Summary-v1.m
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
let
Source = AzureEnterprise.Tables("https://ea.azure.com/rest/1234567"),
Summary = Source{[Key="Summary"]}[Data],
#"NoHeaders" = Table.TransformColumns(Summary,{{"Data",each Table.DemoteHeaders(_) }}),
#"SkipHeaders" = Table.TransformColumns(NoHeaders,{{"Data",each Table.Skip(_,1) }}),
#"Expanded Data" = Table.ExpandTableColumn(SkipHeaders, "Data", {"Column1", "Column2", "Column3"}, {"Data.Column1", "Data.Column2", "Data.Column3"}),
#"Filtered Rows" = Table.SelectRows(#"Expanded Data", each [Data.Column1] <> ""),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Data.Column2"}),
#"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Data.Column1]), "Data.Column1", "Data.Column3"),
#"Removed Columns1" = Table.RemoveColumns(#"Pivoted Column",{"SIE Credit"}),
#"Changed Type" = Table.TransformColumnTypes(#"Removed Columns1",{{"Beginning Balance", type number}, {"New Purchases", type number}, {"Adjustments", type number}, {"Utilized ( subtracted from balance)", type number}, {"Ending Balance", type number}, {"Overage", type number}, {"Service Overage", type number}, {"Charges Billed Separately", type number}, {"Total Usage (Commitment Utilized + Overage)", type number}, {"Total Overage", type number}, {"Azure Marketplace Service Charges <br /> (Billed Separately)", type number}},"en-US")
in
#"Changed Type"
Loading

0 comments on commit 1a513a9

Please sign in to comment.