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
arhomberg
Helper I
Helper I

Iterative Calculation Over Time

Iterative Calculation

 

Hello all!

 

I could use some help with doing a calculation which I believe will end up being iterative.

 

In the table below, I would like to populate the count column (or a new column being that it’s a calculation) that takes the previous months (count * retention) + close_count

 

arhomberg_0-1645730658795.png

 

I am able to easily do this in excel but am not sure how to execute this in DAX.

 

arhomberg_1-1645730658796.png

 

I have included a project file for reference.

 

Any assistance with this would be greatly appreciated!

 

File: https://www.dropbox.com/s/p7yp3u066a1owu4/power_bi_example.pbix?dl=0

 

1 ACCEPTED SOLUTION
lbendlin
Super User
Super User

Thank you for providing sample data.  (Next time please sanitize it)

 

This is impossible to do in Power BI DAX but relatively easy to achieve in Power Query M.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc67DcAwCATQXagtzOH4wyyR918jTuMkKDRc8Q7EeZJoFmRVSqRsuGP0NYXNaKZVKE8B3GTlh4/NXmoobQuEUT3310vDvI7wrG0RbsUpJNoDQtFfmRc=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [fulldate = _t, close_count = _t, count = _t, retention = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"fulldate", type date}, {"close_count", type number}, {"count", type number}, {"retention", type number}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type",null,0,Replacer.ReplaceValue,{"close_count"}),
    #"Added Index" = Table.AddIndexColumn(#"Replaced Value", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Count2", each List.Accumulate({1..[Index]},287,(state,current)=> state * #"Added Index"{current-1}[retention] + #"Added Index"{current-1}[close_count]))
in
    #"Added Custom"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

View solution in original post

5 REPLIES 5
lbendlin
Super User
Super User

Thank you for providing sample data.  (Next time please sanitize it)

 

This is impossible to do in Power BI DAX but relatively easy to achieve in Power Query M.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc67DcAwCATQXagtzOH4wyyR918jTuMkKDRc8Q7EeZJoFmRVSqRsuGP0NYXNaKZVKE8B3GTlh4/NXmoobQuEUT3310vDvI7wrG0RbsUpJNoDQtFfmRc=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [fulldate = _t, close_count = _t, count = _t, retention = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"fulldate", type date}, {"close_count", type number}, {"count", type number}, {"retention", type number}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type",null,0,Replacer.ReplaceValue,{"close_count"}),
    #"Added Index" = Table.AddIndexColumn(#"Replaced Value", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Count2", each List.Accumulate({1..[Index]},287,(state,current)=> state * #"Added Index"{current-1}[retention] + #"Added Index"{current-1}[close_count]))
in
    #"Added Custom"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

@lbendlinAs a follow-up, I see that you have the value 287 hard coded in. Is it possible to select the value in the first row of the 'count' colum instead?

sure

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc67DcAwCATQXagtzOH4wyyR918jTuMkKDRc8Q7EeZJoFmRVSqRsuGP0NYXNaKZVKE8B3GTlh4/NXmoobQuEUT3310vDvI7wrG0RbsUpJNoDQtFfmRc=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [fulldate = _t, close_count = _t, count = _t, retention = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"fulldate", type date}, {"close_count", type number}, {"count", type number}, {"retention", type number}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type",null,0,Replacer.ReplaceValue,{"close_count"}),
    #"Added Index" = Table.AddIndexColumn(#"Replaced Value", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Count2", each List.Accumulate({1..[Index]},#"Added Index"{0}[count],(state,current)=> state * #"Added Index"{current-1}[retention] + #"Added Index"{current-1}[close_count]))
in
    #"Added Custom"

@lbendlinThank you!

@lbendlinThanks for the assistance with this, it is greatly appreciated!

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.