cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Pbi07
Helper IV
Helper IV

Previous working day Total

I am trying to get a total for the previous working day total in my model 

 

My data is structured as below 

PO NoPurch DateQuantity
10000830-Sep-2140
1000101-Oct-2115
1000114-Oct-2120
10010015-Oct-2120
10010415-Oct-2150
10010118-Oct-21125
10010318-Oct-2125

 

The total for previous day should consider that 

1. if it is first day of month, previous Qty should show the total as the same as the current Qty 

2. For Monday, previous working day should be showing Friday qty 

 

Expected result is 

Purch DateTotal QtyPrevious qty
30-Sep-21400
1-Oct-211515
4-Oct-212015
15-Oct-21700
18-Oct-2115070

 

Tried using the measure 

Previous Work Day Qty =
var MaxDate = MAXX(FILTER(ALL('Calendar'), 'Calendar'[Date] < SELECTEDVALUE(Calendar[Date])), Calendar[Date])
return
CALCULATE(
SUM('Purch Fact'[Quantity]), FILTER(ALL('Calendar'), Calendar[Date] = MaxDate)
)
1 ACCEPTED SOLUTION
yingyinr
Community Support
Community Support

Hi @Pbi07 ,

I updated your sample pbix file(see attachment), please check whether that is what you want.

Previous Work Day Qty = 
VAR _curdate =
    SELECTEDVALUE ( 'Purch Fact'[Purch Date] )
VAR _preworkdate =
    CALCULATE (
        MAX ( 'Calendar'[Date] ),
        FILTER (
            ALL ( 'Calendar' ),
            'Calendar'[Date] < _curdate
                && WEEKDAY ( 'Calendar'[Date], 2 ) <= 5
        )
    )
RETURN
    IF (
        DAY ( _curdate ) = 1,
        [Total Qty],
        SUMX (
            FILTER ( ALLSELECTED ( 'Purch Fact' ), 'Purch Fact'[Purch Date] = _preworkdate ),
            [Total Qty]
        )
    ) + 0

yingyinr_0-1636014005376.png

 

Best Regards

Community Support Team _ Rena
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
yingyinr
Community Support
Community Support

Hi @Pbi07 ,

I updated your sample pbix file(see attachment), please check whether that is what you want.

Previous Work Day Qty = 
VAR _curdate =
    SELECTEDVALUE ( 'Purch Fact'[Purch Date] )
VAR _preworkdate =
    CALCULATE (
        MAX ( 'Calendar'[Date] ),
        FILTER (
            ALL ( 'Calendar' ),
            'Calendar'[Date] < _curdate
                && WEEKDAY ( 'Calendar'[Date], 2 ) <= 5
        )
    )
RETURN
    IF (
        DAY ( _curdate ) = 1,
        [Total Qty],
        SUMX (
            FILTER ( ALLSELECTED ( 'Purch Fact' ), 'Purch Fact'[Purch Date] = _preworkdate ),
            [Total Qty]
        )
    ) + 0

yingyinr_0-1636014005376.png

 

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

I created a calculated column in your calendar table in order to help define weekdays.

 

Picture3.png

 

Previous Work Day Qty =
VAR currentdate =
MAX ( 'Calendar'[Date] )
VAR previousworkingdate =
MAXX (
FILTER (
ALL ( 'Calendar' ),
'Calendar'[Date] < currentdate
&& NOT ( 'Calendar'[Weekdayname CC] IN { "Saturday", "Sunday" } )
),
'Calendar'[Date]
)
RETURN
IF (
HASONEVALUE ( 'Calendar'[Date] ),
IF (
NOT ( ISBLANK ( [Total Qty] ) ),
SWITCH (
TRUE (),
SELECTEDVALUE ( 'Calendar'[Date] ) = STARTOFMONTH ( 'Calendar'[Date] ), [Total Qty],
CALCULATE ( [Total Qty], 'Calendar'[Date] = previousworkingdate )
) + 0
)
)
 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thanks @Jihwan_Kim 

 

I can see it working in that model. 

Trying to understand how this is working. When i try to bring this into my model, my total is showing up as 0, eventhough there is value. WIll you be able to explain that expression in the return parameter please. 

Also, is that HASONEVALUE being false returning that 0 for my expression. Bit confused with it. 

 

Hi, 

Thank you for your message.

Sorry to say that it is quite difficult to fully understand your question without seeing the model and visualization.

I think you already shared the link of your model, but if it is different now, could you please let me know again the link or your model?

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thanks @Jihwan_Kim . Let me see if i can take a sample of that model for you. 

 

Just curious what is the significance of that HASONEVALUE in the measure. Looks to me that it is causing the issue in my measure. Trying to see if i can avoid and use it. 

amitchandak
Super User
Super User

@Pbi07 , You can try like these examples

 

This Day = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Date]=max('Date'[Date])))
Last Day = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Date]=max('Date'[Date])-1))
Last Day = CALCULATE(sum('Table'[Qty]), previousday('Date'[Date]))

 

 

Day Intelligence - Last day, last non continous day
https://medium.com/@amitchandak.1978/power-bi-day-intelligence-questions-time-intelligence-5-5-5c324...



Power BI Features || Datamarts: https://youtu.be/8tskWsJTEpg || Field Parameters : https://youtu.be/lqF3Wa1FllE?t=70
Time Intelligence Decoded : https://youtu.be/aU2aKbnHuWs&t=145s
Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
Dashboard of My Blogs !! Connect on Linkedin !! Subscribe to my youtube Channel !!
Want To Learn Power BI | Beginners !! Advance Concepts !! Power BI For Tableau User !!

Helpful resources

Announcements
August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 24 without aka link and time 768x460.jpg

Ted's Dev Camp - July 28, 2022

Watch Session 24 of Ted's Dev Camp along with past sessions!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors