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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
jsteffe
Helper III
Helper III

Iterative calculation

Hello,

I get the following table with products and stocks

exBI.png

I get the stock value only for my last date (2014-06-14) for each product and I want to get it for all previous days ...

For example : my stock value for product 2009100 and date 2014-06-13 will be 33 (stock at 2016-06-14) + 4 (outputs at 2016-06-14) - 1 (input at 2016-06-14) = 36

 

Is there a way to do this iterative calculation ? Start from the last date for each product and complete the table ?

Thanks for your help ...

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

I was going to tell you that you can use a calculated column BUT there is no way to tell powerbi to to run calculations in a certain order (or recursive). So the formula would be fairly complex because you have to do (in your calculated column)

- look for the maximum date available for this inventory id

- determine the stock amount

- iterate through all of the rows from that max date to current date, summing all in, out 

 

so something along the lines of
calcStock=
VAR thisProduct = table[product_id]

VAR thisDate = table[inv_date]

VAR maxDate=MAXX(FILTER(table;table[product_id] = thisProduct);table[inv_date])
VAR endStock=MAXX(FILTER(table);table[product_id]=thisProduct && table[inv_date]=maxDate);  table[end_day_stock_value])
VAR differential= SUMX(FILTER(Table;table[product_id]=thisProduct && table[inv_date]>=thisDate);table[output]-table[input])

RETURN
endStock+differential

 

(I haven't tested but SHOULD work)

View solution in original post

Anonymous
Not applicable

Hi @jsteffe 

 

The dax which is written by @Anonymous  is correct.

One change needs to be done in it for differential

 

 

New Stock =
VAR thisProduct = 'Table'[product_id]

VAR thisDate = 'Table'[inv_date]

VAR maxDate=MAXX(FILTER('Table','Table'[product_id] = thisProduct),'Table'[inv_date])
VAR endStock=MAXX(FILTER('Table','Table'[product_id]=thisProduct && 'Table'[inv_date]=maxDate),'Table'[Stock])
VAR differential= SUMX(FILTER('Table','Table'[product_id]=thisProduct && 'Table'[inv_date]>=thisDate && 'Table'[inv_date]<maxDate),'Table'[output]-'Table'[input])

RETURN
endStock+differential
 
 
Thanks & regards,
Pravin Wattamwar
www.linkedin.com/in/pravin-p-wattamwar

If I resolve your problem Mark it as a solution and give kudos.

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hi @jsteffe 

 

The dax which is written by @Anonymous  is correct.

One change needs to be done in it for differential

 

 

New Stock =
VAR thisProduct = 'Table'[product_id]

VAR thisDate = 'Table'[inv_date]

VAR maxDate=MAXX(FILTER('Table','Table'[product_id] = thisProduct),'Table'[inv_date])
VAR endStock=MAXX(FILTER('Table','Table'[product_id]=thisProduct && 'Table'[inv_date]=maxDate),'Table'[Stock])
VAR differential= SUMX(FILTER('Table','Table'[product_id]=thisProduct && 'Table'[inv_date]>=thisDate && 'Table'[inv_date]<maxDate),'Table'[output]-'Table'[input])

RETURN
endStock+differential
 
 
Thanks & regards,
Pravin Wattamwar
www.linkedin.com/in/pravin-p-wattamwar

If I resolve your problem Mark it as a solution and give kudos.

Thanks a lot for your precise answer : it perfectly works !

 

Anonymous
Not applicable

I was going to tell you that you can use a calculated column BUT there is no way to tell powerbi to to run calculations in a certain order (or recursive). So the formula would be fairly complex because you have to do (in your calculated column)

- look for the maximum date available for this inventory id

- determine the stock amount

- iterate through all of the rows from that max date to current date, summing all in, out 

 

so something along the lines of
calcStock=
VAR thisProduct = table[product_id]

VAR thisDate = table[inv_date]

VAR maxDate=MAXX(FILTER(table;table[product_id] = thisProduct);table[inv_date])
VAR endStock=MAXX(FILTER(table);table[product_id]=thisProduct && table[inv_date]=maxDate);  table[end_day_stock_value])
VAR differential= SUMX(FILTER(Table;table[product_id]=thisProduct && table[inv_date]>=thisDate);table[output]-table[input])

RETURN
endStock+differential

 

(I haven't tested but SHOULD work)

Anonymous
Not applicable

Hi @Anonymous thanks for the fix!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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