Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hey all,
I have a report with so much data that I'm trying to reduce my Calculated Columns, to reduce the refresh time for my users, replicating them in Power Query instead. I've done OK so far, but I have a 'Running Total' column that I can't for the life of me work out how to produce within Power Query.
The DAX I use to create the calculated column is:
Running Total = CALCULATE(SUM(MonthlySavings2223_Data[Savings per month]),
ALL(MonthlySavings2223_Data),
MonthlySavings2223_Data[Date] <= EARLIER (MonthlySavings2223_Data[Date]),
MonthlySavings2223_Data[Delivery Risk] = "Implemented")
If someone could point me in the right direction for how I'd replicate that in Power Query, I'd be so happy!
Solved! Go to Solution.
See this blog post
Create Running Totals in Power Query (excelguru.ca)
Without looking at your data, best way to replicate your DAX measure in Power Query would look something like this...
let
// Replace this with your source step
Source = YourSourceTableName,
// Sort by Date
SortedTable = Table.Sort(Source, {{"Date", Order.Ascending}}),
// Filter rows where "Delivery Risk" is "Implemented"
FilteredTable = Table.SelectRows(SortedTable, each [Delivery Risk] = "Implemented"),
// Add a custom column for running total
RunningTotal = Table.AddColumn(FilteredTable, "Running Total", each List.Sum(List.FirstN(FilteredTable[Savings per month], [Index] + 1))),
// Add an index column for use in the running total calculation
AddedIndex = Table.AddIndexColumn(RunningTotal, "Index", 0, 1, Int64.Type)
in
AddedIndex
Proud to be a Super User!
Hi,
one solution could be:
1. Sort the date coulmn Ascending
2. create an Index column strating from 1
3. use the fx button to add a step with the following code:
= Table.AddColumn(
#"Added Index",
"Running Total",
(OutTable) =>
List.Sum(
Table.SelectRows(
#"Added Index",
(InTable) => InTable[Index] <= OutTable[Index]
and
InTable[Delivery Risk] = OutTable[Delivery Risk])[Savings per month]
)
)
If I answered your question, please mark my post as solution, Appreciate your Kudos 👍
Hi,
one solution could be:
1. Sort the date coulmn Ascending
2. create an Index column strating from 1
3. use the fx button to add a step with the following code:
= Table.AddColumn(
#"Added Index",
"Running Total",
(OutTable) =>
List.Sum(
Table.SelectRows(
#"Added Index",
(InTable) => InTable[Index] <= OutTable[Index]
and
InTable[Delivery Risk] = OutTable[Delivery Risk])[Savings per month]
)
)
If I answered your question, please mark my post as solution, Appreciate your Kudos 👍
See this blog post
Create Running Totals in Power Query (excelguru.ca)
Without looking at your data, best way to replicate your DAX measure in Power Query would look something like this...
let
// Replace this with your source step
Source = YourSourceTableName,
// Sort by Date
SortedTable = Table.Sort(Source, {{"Date", Order.Ascending}}),
// Filter rows where "Delivery Risk" is "Implemented"
FilteredTable = Table.SelectRows(SortedTable, each [Delivery Risk] = "Implemented"),
// Add a custom column for running total
RunningTotal = Table.AddColumn(FilteredTable, "Running Total", each List.Sum(List.FirstN(FilteredTable[Savings per month], [Index] + 1))),
// Add an index column for use in the running total calculation
AddedIndex = Table.AddIndexColumn(RunningTotal, "Index", 0, 1, Int64.Type)
in
AddedIndex
Proud to be a Super User!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
101 | |
66 | |
48 | |
39 | |
34 |
User | Count |
---|---|
166 | |
112 | |
60 | |
56 | |
37 |