March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
HI i need help on how to post calculation in power query.
i need to get the total of the Observer column per month and divide it with the total of my parameters each Safe and At risk.
Thanks in advance
Solved! Go to Solution.
netteSJ,
Starting with columns Company, Date and Parameters here is method for Power Query.
The NaNs occur when Total Observations are zero. You may wish to filter out those rows, add some test code for zeroes or replace NaN with some text like N/A.
Here is my sample data
...here is the result
...and here is the M code
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,
{{"Company", type text}, {"Date", type datetime}, {"Parameters", type text}}),
#"Calculated Start of Month" = Table.TransformColumns(#"Changed Type",
{{"Date", Date.StartOfMonth, type datetime}}),
#"Rename Columns to Start of Month" = Table.RenameColumns(#"Calculated Start of Month",
{{"Date", "Month Starting"}}),
#"Add Count" = Table.AddColumn(#"Rename Columns to Start of Month",
"Count",
each 1,
Int64.Type),
#"Pivot Parameters Column" = Table.Pivot(#"Add Count",
List.Distinct(#"Add Count"[Parameters]),
"Parameters",
"Count",
List.Sum),
#"Replace nulls with Zeroes" = Table.ReplaceValue(#"Pivot Parameters Column",
null,
0,
Replacer.ReplaceValue,
{"Safe", "At Risk", "-"}),
#"Group by Company and Month Starting" = Table.Group(#"Replace nulls with Zeroes",
{"Company", "Month Starting"},
{
{"Safe", each List.Sum([Safe]), type nullable number},
{"At Risk", each List.Sum([At Risk]), type nullable number}
}),
#"Add Total Observations" = Table.AddColumn(#"Group by Company and Month Starting",
"Total Observations",
each [Safe] + [At Risk],
Int64.Type),
#"Add % At Risk" = Table.AddColumn(#"Add Total Observations",
"% At Risk",
each [At Risk] / [Total Observations],
Percentage.Type),
#"Add % Safe" = Table.AddColumn(#"Add % At Risk",
"% Safe",
each [Safe] / [Total Observations],
Percentage.Type)
in
#"Add % Safe"
netteSJ,
Starting with columns Company, Date and Parameters here is method for Power Query.
The NaNs occur when Total Observations are zero. You may wish to filter out those rows, add some test code for zeroes or replace NaN with some text like N/A.
Here is my sample data
...here is the result
...and here is the M code
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,
{{"Company", type text}, {"Date", type datetime}, {"Parameters", type text}}),
#"Calculated Start of Month" = Table.TransformColumns(#"Changed Type",
{{"Date", Date.StartOfMonth, type datetime}}),
#"Rename Columns to Start of Month" = Table.RenameColumns(#"Calculated Start of Month",
{{"Date", "Month Starting"}}),
#"Add Count" = Table.AddColumn(#"Rename Columns to Start of Month",
"Count",
each 1,
Int64.Type),
#"Pivot Parameters Column" = Table.Pivot(#"Add Count",
List.Distinct(#"Add Count"[Parameters]),
"Parameters",
"Count",
List.Sum),
#"Replace nulls with Zeroes" = Table.ReplaceValue(#"Pivot Parameters Column",
null,
0,
Replacer.ReplaceValue,
{"Safe", "At Risk", "-"}),
#"Group by Company and Month Starting" = Table.Group(#"Replace nulls with Zeroes",
{"Company", "Month Starting"},
{
{"Safe", each List.Sum([Safe]), type nullable number},
{"At Risk", each List.Sum([At Risk]), type nullable number}
}),
#"Add Total Observations" = Table.AddColumn(#"Group by Company and Month Starting",
"Total Observations",
each [Safe] + [At Risk],
Int64.Type),
#"Add % At Risk" = Table.AddColumn(#"Add Total Observations",
"% At Risk",
each [At Risk] / [Total Observations],
Percentage.Type),
#"Add % Safe" = Table.AddColumn(#"Add % At Risk",
"% Safe",
each [Safe] / [Total Observations],
Percentage.Type)
in
#"Add % Safe"
Thanks for your quick help😊
If you don't, strictly, need a solution in Power Query, the calculation you describe is ideally suited to solution in DAX + visualisation. I will illustrate the DAX solution. I loaded this dummy data into a data model.
Then, I created two DAX measures:
Count of Observations := COUNTROWS('Observations')
and
Fraction of Observations :=
DIVIDE(
[Count of Observations],
CALCULATE(
[Count of Observations],
REMOVEFILTERS('Observations'[Parameters])
)
)
These measures can then be used as values in matrix visuals,
Hi Collinsg, i need to have it in Power Query. Below is data i want to have. I need to get the total Observations submitted using Column of Observer and divide it with the Total At risk and Safe to get the percentage. Which i can filter by company and month.
Main Data/ Source file
Please provide sample data that covers your issue or question completely, in a usable format (not as a screenshot).
https://community.powerbi.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-Forum/ba-...
Please show the expected outcome based on the sample data you provided.
https://community.powerbi.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447523
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
21 | |
16 | |
13 | |
12 | |
9 |
User | Count |
---|---|
36 | |
31 | |
20 | |
19 | |
17 |