Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
VJ_Lsf
Frequent Visitor

calculate a running total based on a filter

Hi,

I need to calculate a running total based on a filter, Customer in the table below. Balance column is calculated subtracting Added column from Closed column for Each Customer. I need to have a running balance by each customer. Can I do this in calculated column instead of a measure. Thanks for the help.

 

VJ_Lsf_0-1744154044958.png

 

 

 

 

1 ACCEPTED SOLUTION
BeaBF
Super User
Super User

@VJ_Lsf Hi! Here the Advanced Editor Codefor your scope:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnR0VNJRMgFiQwOlWB0UAUMkASMjkIgRkogZSMAYScACJGACFnBycgJyjEECpkgCYFPNkASAdgIJcwwRC6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Balance = _t, Week = _t]),

// Convert column types
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer", type text}, {"Balance", Int64.Type}, {"Week", Int64.Type}}),

// Sort by Customer, then Week ascending
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"Customer", Order.Ascending}, {"Week", Order.Ascending}}),

// Add Index by Customer
#"Grouped" = Table.Group(#"Sorted Rows", {"Customer"}, {
{"AllData", each
Table.AddIndexColumn(_, "Index", 0, 1, Int64.Type)
}
}),

// Expand the grouped table
#"Expanded Table" = Table.ExpandTableColumn(#"Grouped", "AllData", { "Balance", "Week", "Index"}),

// Add Running Total using List.Sum over previous rows
#"Added Running Total" = Table.AddColumn(#"Expanded Table", "RunningBalance", (row) =>
let
customer = row[Customer],
index = row[Index],
balances = Table.SelectRows(#"Expanded Table", each [Customer] = customer and [Index] <= index)[Balance]
in
List.Sum(balances)
),

// Remove the index if not needed
#"Removed Columns" = Table.RemoveColumns(#"Added Running Total",{"Index"})

in
#"Removed Columns"

 

You'll obtain the Running Balance for each Customer by Week ASC:

BeaBF_0-1744181542035.png

 

If it's ok, please accept my answer as solution!

 

BBF

View solution in original post

2 REPLIES 2
SundarRaj
Solution Supplier
Solution Supplier

Hi @VJ_Lsf , there's another solution you could look. I haven't made the grouping here since there were only one set of customers. If there are more, you can do the grouping by customer first and then apply the below code for each and every grouped table. Thanks!

SundarRaj_0-1744188946539.png

SundarRaj_1-1744188964132.png

Here's the code:
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
Sum = List.Skip(List.Accumulate(Source[Balance], {0}, (s,c) => s & {List.Last(s) + c})),
Add = Source,
RemCols = Table.AddIndexColumn(Table.RemoveColumns(Add,{"Balance"}),"Balance",0,1),
Table = Table.TransformColumns(RemCols,{"Balance", each Sum{_}})
in
Table

 

Sundar Rajagopalan
BeaBF
Super User
Super User

@VJ_Lsf Hi! Here the Advanced Editor Codefor your scope:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnR0VNJRMgFiQwOlWB0UAUMkASMjkIgRkogZSMAYScACJGACFnBycgJyjEECpkgCYFPNkASAdgIJcwwRC6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Balance = _t, Week = _t]),

// Convert column types
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer", type text}, {"Balance", Int64.Type}, {"Week", Int64.Type}}),

// Sort by Customer, then Week ascending
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"Customer", Order.Ascending}, {"Week", Order.Ascending}}),

// Add Index by Customer
#"Grouped" = Table.Group(#"Sorted Rows", {"Customer"}, {
{"AllData", each
Table.AddIndexColumn(_, "Index", 0, 1, Int64.Type)
}
}),

// Expand the grouped table
#"Expanded Table" = Table.ExpandTableColumn(#"Grouped", "AllData", { "Balance", "Week", "Index"}),

// Add Running Total using List.Sum over previous rows
#"Added Running Total" = Table.AddColumn(#"Expanded Table", "RunningBalance", (row) =>
let
customer = row[Customer],
index = row[Index],
balances = Table.SelectRows(#"Expanded Table", each [Customer] = customer and [Index] <= index)[Balance]
in
List.Sum(balances)
),

// Remove the index if not needed
#"Removed Columns" = Table.RemoveColumns(#"Added Running Total",{"Index"})

in
#"Removed Columns"

 

You'll obtain the Running Balance for each Customer by Week ASC:

BeaBF_0-1744181542035.png

 

If it's ok, please accept my answer as solution!

 

BBF

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.