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

Use previous days value to calculate current day's value

Hello people!

I have a question regarding using Previous day's closing value as starting point of a calculation to current day's value & repeat the same logic for future days as well.

DateInputsBIInboundPlan UsageEIRankPrevious day valuePrevious day closing value
Wednesday, May 13, 2020WC2 - Segs/Foil0048,833-48,8331055/12/2020 -48,833
Wednesday, May 13, 2020Prime00001055/12/2020 0:000
Wednesday, May 13, 2020Shred0060,102-60,1021055/12/2020 0:00-60,102
Wednesday, May 13, 2020RSI0048,833-48,8331055/12/2020 0:00-48,833
Wednesday, May 13, 2020WC1 - PS/MLC0052,589-52,5891055/12/2020 0:00-52,589
Wednesday, May 13, 2020WC3 - 1x/5x/6x0063,858-63,8581055/12/2020 0:00-63,858
Wednesday, May 13, 2020RAR0093,909-93,9091055/12/2020 0:00-93,909
Wednesday, May 13, 2020Hardeners007,513-7,5131055/12/2020 0:00-7,513
Thursday, May 14, 2020Shred167,225210,00047,581329,6441135/13/2020 0:00-60,102
Thursday, May 14, 2020RSI2,252,565126,00038,6592,339,9061135/13/2020 0:00-48,833
Thursday, May 14, 2020Prime576,53500576,5351135/13/2020 0:000
Thursday, May 14, 2020WC1 - PS/MLC103,45542,00041,633103,8221135/13/2020 0:00-52,589
Thursday, May 14, 2020WC2 - Segs/Foil77,88084,00038,659123,2211135/13/2020 0:00-48,833
Thursday, May 14, 2020WC3 - 1x/5x/6x128,665210,00050,554288,1111135/13/2020 0:00-63,858
Thursday, May 14, 2020RAR-632,261074,345-706,6061135/13/2020 0:00-93,909
Thursday, May 14, 2020Hardeners49,20505,94843,2571135/13/2020 0:00-7,513
Friday, May 15, 2020RSI0168,00048,833119,1671215/14/2020 0:002,339,906
Friday, May 15, 2020Prime00001215/14/2020 0:00576,535
Friday, May 15, 2020RAR0093,909-93,9091215/14/2020 0:00-706,606
Friday, May 15, 2020Hardeners007,513-7,5131215/14/2020 0:0043,257
Friday, May 15, 2020Shred0252,00060,102191,8981215/14/2020 0:00329,644
Friday, May 15, 2020WC1 - PS/MLC042,00052,589-10,5891215/14/2020 0:00103,822
Friday, May 15, 2020WC2 - Segs/Foil084,00048,83335,1671215/14/2020 0:00123,221
Friday, May 15, 2020WC3 - 1x/5x/6x084,00063,85820,1421215/14/2020 0:00288,111
Saturday, May 16, 2020WC2 - Segs/Foil0048,833-48,8331295/15/2020 0:0035,167
Saturday, May 16, 2020WC3 - 1x/5x/6x0063,858-63,8581295/15/2020 0:0020,142
Saturday, May 16, 2020Prime00001295/15/2020 0:000
Saturday, May 16, 2020Shred0060,102-60,1021295/15/2020 0:00191,898
Saturday, May 16, 2020WC1 - PS/MLC0052,589-52,5891295/15/2020 0:00-10,589
Saturday, May 16, 2020RAR0093,909-93,9091295/15/2020 0:00-93,909
Saturday, May 16, 2020Hardeners007,513-7,5131295/15/2020 0:00-7,513
Saturday, May 16, 2020RSI084,00048,83335,1671295/15/2020 0:00119,167

 

I tried using the Rank & previous day methd, but think i'm missing something simple. 

BI is usually populated for only one day

EI = BI + Inbound - Usage 

this is the BI for next day & the calculations continues into the future

 

is this something that could be replicated?

1 ACCEPTED SOLUTION
v-zhenbw-msft
Community Support
Community Support

Hi @lokeswer ,

 

We can use the following measure to meet your requirement.

 

EI = 
VAR min_date =
    CALCULATE ( MIN ( 'Table'[Date] ), ALLSELECTED () )
VAR min_date_value =
    CALCULATE (
        MIN ( 'Table'[Inputs] ),
        FILTER ( ALLSELECTED ( 'Table' ), 'Table'[Date] = min_date )
    )
RETURN
    min_date_value
        + CALCULATE (
            SUM ( 'Table'[Inbound] ),
            FILTER ( ALL ( 'Table'[Date] ), 'Table'[Date] <= MAX ( 'Table'[Date] ) )
        )
        - CALCULATE (
            SUM ( 'Table'[Usage] ),
            FILTER ( ALL ( 'Table'[Date] ), 'Table'[Date] <= MAX ( 'Table'[Date] ) )
        )

 

And the result like this,

 

Use 1.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
v-zhenbw-msft
Community Support
Community Support

Hi @lokeswer ,

 

We can use the following measure to meet your requirement.

 

EI = 
VAR min_date =
    CALCULATE ( MIN ( 'Table'[Date] ), ALLSELECTED () )
VAR min_date_value =
    CALCULATE (
        MIN ( 'Table'[Inputs] ),
        FILTER ( ALLSELECTED ( 'Table' ), 'Table'[Date] = min_date )
    )
RETURN
    min_date_value
        + CALCULATE (
            SUM ( 'Table'[Inbound] ),
            FILTER ( ALL ( 'Table'[Date] ), 'Table'[Date] <= MAX ( 'Table'[Date] ) )
        )
        - CALCULATE (
            SUM ( 'Table'[Usage] ),
            FILTER ( ALL ( 'Table'[Date] ), 'Table'[Date] <= MAX ( 'Table'[Date] ) )
        )

 

And the result like this,

 

Use 1.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-zhenbw-msft  Thanks for the help.

I think this works. Atleast got me to the final solution. I had to create a seperate measure that does the math & then create a calculate column filtering for earlier date, mathing input to get the result. 

 

thanks again

Greg_Deckler
Super User
Super User

@lokeswer - I'm with @AllisonKennedy not exactly certain of what I am looking at and your desired outcome. Please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.

 

But maybe see my article on Mean Time Between Failure (MTBF) which uses EARLIER: http://community.powerbi.com/t5/Community-Blog/Mean-Time-Between-Failure-MTBF-and-Power-BI/ba-p/3395...


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@AllisonKennedy , @Greg_Deckler ,  @parry2k  Thanks for chiming in.

 

DateInputsBIInboundUsageEI
5/1/2020A10129
5/1/2020B10248
5/1/2020C10367
5/2/2020A9128
5/2/2020B8246
5/2/2020C7364
5/3/2020A8127
5/3/2020B6244
5/3/2020C4361
5/4/2020A7126
5/4/2020B4242
5/4/2020C136-2

 

This table is what i'm trying to get to,

Steps:

5/1/2020 = BI is already given by inputs , so EI = BI + inbound - Planned usage

5/2/2020 = BI is the EI of 5/1/2020(Previous day) matching corresponding inputs, hence the EI = BI +inbound - Planned usage

5/3/2020 = BI is the EI of 5/2/2020(Previous day) matching corresponding inputs, hence the EI = BI +inbound - Planned usage

5/4/2020 = BI is the EI of 5/3/2020(Previous day) matching corresponding inputs, hence the EI = BI +inbound - Planned usage

 

The dates & the inputs are both important. this is where i'm getting in circles with recursive 

I would like to carry this formula for future dates as well!

 

AllisonKennedy
Super User
Super User

Sorry I'm not sure I fully understand what you're trying to do. Is the table you posted the desired result or what you've been trying? What is the desired result? 

 

Are you wanting a cumulative measure adding previous day to current and continuing on? If so, you will need a DimDate table and DAX time intelligence (either DATESYTD or DATESBETWEEN)

 

https://allisonkennedycv.blogspot.com/2020/04/dimdate-what-why-and-how.html


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

@lokeswer you need to run cumulative total for your columns and then get previous day value. There are many posts on how to create cumulative/running total in Power BI, here is link to one or you can use quick measures for running total.

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

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.