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
Jacob_Steagald
Frequent Visitor

How to exclude weekends from on time shipping calculation

I am creating an on time shipping report that calculates whether orders, received by 3:15 pm, go out the same day or, if they come in after 3:15 pm, ship the next business day.

 

I have created the calculated column that does the basic math to figure out if they went out on the same day but I need to exlude weekends because all of my Friday afternoon orders are coming back as going out late even though they ship by end of day Monday, which technically means they were on time.

 

The calculation I am using is this:
 
On Time = 'Shipping'[Date added] = 'Shipping'[Date shipped] || ( 'Shipping'[Date shipped] = 'Shipping'[Date added] + 1 && 'Shipping'[Time added] > TIME ( 15, 15, 0 ) )
 
Is there a convenient way to make it exclude weekends? 
1 ACCEPTED SOLUTION

Hi @Jacob_Steagald ,

You can update the formula of calculated column [On Time] as below, please find the details in the attachment.

On Time = 
IF (
    'Shipping'[Date added] = 'Shipping'[Date shipped]
        || (
            'Shipping'[Date shipped] = 'Shipping'[Date added] + 1
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
        )
        || (
            WEEKDAY ( 'Shipping'[Date added], 2 ) = 5
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
                && 'Shipping'[Date shipped] = 'Shipping'[Date added] + 3
        ),
    "On Time"
)

vyiruanmsft_0-1685929345112.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

3 REPLIES 3
Jacob_Steagald
Frequent Visitor

 

Order NumberDate AddedTime AddedDate Shipped
1Thursday, January 12, 202312:54:04 PMThursday, January 12, 2023
2Thursday, January 12, 20232:25:14 PMFriday, January 13, 2023
3Thursday, January 12, 20234:04:25 PMFriday, January 13, 2023
4Friday, January 13, 202310:14:46 AMFriday, January 13, 2023
5Friday, January 13, 20233:01:14 PMFriday, January 13, 2023
6Friday, January 13, 20234:45:13 PMMonday, January 16, 2023
7Monday, January 16, 20232:11:45 PMMonday, January 16, 2023

 

This is a sample set from our data. As you can see, Orders 1, 4, 5, and 7 all shipped out on the same day.

Order 2 should be Late as it was received BEFORE 3:15 and didn't ship out until the next day.

Order 3 should be considered On Time because it came in AFTER 3:15 and was shipped out the next day.

All of that is accounted for in my previous column. 

 

Order 6 is really what I am focused on. That order came in on a Friday AFTER the 3:15 deadline and then shipped on the next business day, Monday. By rule that should be considered On Time. However, neither my original model nor the one supplied above accounts for them. My model marks it as late and the one you supplied simply doesn't mark it at all.

 

I'd appreciate any help you can offer

Hi @Jacob_Steagald ,

You can update the formula of calculated column [On Time] as below, please find the details in the attachment.

On Time = 
IF (
    'Shipping'[Date added] = 'Shipping'[Date shipped]
        || (
            'Shipping'[Date shipped] = 'Shipping'[Date added] + 1
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
        )
        || (
            WEEKDAY ( 'Shipping'[Date added], 2 ) = 5
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
                && 'Shipping'[Date shipped] = 'Shipping'[Date added] + 3
        ),
    "On Time"
)

vyiruanmsft_0-1685929345112.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.
v-yiruan-msft
Community Support
Community Support

Hi @Jacob_Steagald ,

You can update the formula of calculated column [On Time] as below and check if it can return the expected result...

On Time =
IF (
    'Shipping'[Date added] = 'Shipping'[Date shipped]
        || (
            'Shipping'[Date shipped] = 'Shipping'[Date added] + 1
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
        )
        || (
            WEEKDAY ( 'Shipping'[Time added], 2 ) = 5
                && TIMEVALUE ( 'Shipping'[Time added] ) > TIME ( 15, 15, 0 )
                && 'Shipping'[Date shipped] = 'Shipping'[Date added] + 3
        ),
    "On Time"
)

If the above one can't help you, please provide some raw data in the table 'Shipping' (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It would be helpful to find out the solution. You can refer the following links to share the required info:

How to provide sample data in the Power BI Forum

 

And It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.

How to upload PBI in Community

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.

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.