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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Anonymous
Not applicable

Working Days between two periods

Hello  -  This formula works for counting positive days between two periods  (weekdays only).     Meaning...this assumes the Delivery Date comes after the Order Date.  

 

I am actually using this formula for tracking on-time shipments....so some early shipments actually ship before the due date.    In this case, this formula just shows a blank result.    I need it to somehow also count the number of weekdays even if the actual ship date comes before the due date.      For example:      Due Date:   Feb 17    Actual Ship Date:   Feb 12      Even if it shows the result with a negative....like   - 3 Days   this is fine.   

 

Any ideas?

 

Sales DeliveryWorking Days =
CALCULATE(
    COUNTROWS ( DateTable),
    DATESBETWEEN ( DateTable[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped] -0 ),
    DateTable[DateIsWorkingDay] = TRUE,
    ALL ( 'Flu Shipped' )
)

 

 

 
2 ACCEPTED SOLUTIONS

Yes, like I mentioned - you have to add your workday-filter.

It should work like you did before.

As I had to build the sample data from scratch, I've allowed myself to skip that additional column.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

Anonymous
Not applicable

Thank you Imke!!     Here is the final formula for anyone else that may need this.    Again, this counts the number of workdays between one period and the next   (in this...between Due Dates  and  Ship Dates).     And also accounts for if the ship date comes earlier than the due date.  

 

WDC =
If( 'Flu Shipped'[Due Date] < 'Flu Shipped'[Date Shipped],
CALCULATE(
COUNTROWS( DateTable ),
DATESBETWEEN ( DateTable[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped]),DateTable[DateIsWorkingDay]= True,
    ALL ( 'Flu Shipped' )
),

CALCULATE(
COUNTROWS( DateTable ),
DATESBETWEEN ( DateTable[Date], 'Flu Shipped'[Date Shipped], 'Flu Shipped'[Due Date]), DateTable[DateIsWorkingDay]=True,
    ALL ( 'Flu Shipped' )
) * -1)

View solution in original post

9 REPLIES 9
ImkeF
Super User
Super User

Hi @Anonymous 

how about this?

 

WD = if ( 

'Flu Shipped'[Due Date] < 'Flu Shipped'[Date Shipped],
CALCULATE(
    COUNTROWS ( DateTable),
    DATESBETWEEN ( DateTable[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped] -0 ),
    DateTable[DateIsWorkingDay] = TRUE,
    ALL ( 'Flu Shipped' ),

CALCULATE(
    COUNTROWS ( DateTable),
    DATESBETWEEN ( DateTable[Date], 'Flu Shipped'[Date Shipped] -0,  'Flu Shipped'[Due Date],  ) * -1,
    DateTable[DateIsWorkingDay] = TRUE,
    ALL ( 'Flu Shipped'
) )

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Anonymous
Not applicable

I tried it.   I am getting the error: 

 

A function "Calculate" has been used in a True/False expression that is used as a Table filter expression.   This is not allowed.  

 Oh yes, sorry - the *-1 has to be moved:

 

WD = if ( 

'Flu Shipped'[Due Date] < 'Flu Shipped'[Date Shipped],

CALCULATE(
    COUNTROWS ( DateTable),
    DATESBETWEEN ( DateTable[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped] -0 ),
    DateTable[DateIsWorkingDay] = TRUE,
    ALL ( 'Flu Shipped' ),

CALCULATE(
    COUNTROWS ( DateTable),
    DATESBETWEEN ( DateTable[Date], 'Flu Shipped'[Date Shipped] -0,  'Flu Shipped'[Due Date],  ) ,
    DateTable[DateIsWorkingDay] = TRUE,
    ALL ( 'Flu Shipped' 
) * -1 )

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Anonymous
Not applicable

Hi Imke  -  I'm still getting the same message.   

 

I think maybe it has something to do with the IF statement and the Calculate Statments?   

https://community.powerbi.com/t5/Quick-Measures-Gallery/Net-Work-Days/m-p/367362#M109


@ 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!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

Hi working for me, but there might be typos in my post. Please compare with screenshot:

image.png

 

 

WDC = 
If( 'Flu Shipped'[Due Date] < 'Flu Shipped'[Date Shipped],
CALCULATE(
COUNTROWS( 'Calendar' ),
DATESBETWEEN ( Calendar[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped]),
    ALL ( 'Flu Shipped' )
),

CALCULATE(
COUNTROWS( 'Calendar' ),
DATESBETWEEN ( Calendar[Date],   'Flu Shipped'[Date Shipped], 'Flu Shipped'[Due Date]) ,
    ALL ( 'Flu Shipped' )
) * -1)

.. just be aware that the holiday-filter is missing in my sample..

 

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Anonymous
Not applicable

Hi Imke   -   Your formula seems to be counting total days.    I am just looking for week days.     For example, to use your numbers below there are not 32 "work days" between January 1 and Feb 1.   

Yes, like I mentioned - you have to add your workday-filter.

It should work like you did before.

As I had to build the sample data from scratch, I've allowed myself to skip that additional column.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Anonymous
Not applicable

Thank you Imke!!     Here is the final formula for anyone else that may need this.    Again, this counts the number of workdays between one period and the next   (in this...between Due Dates  and  Ship Dates).     And also accounts for if the ship date comes earlier than the due date.  

 

WDC =
If( 'Flu Shipped'[Due Date] < 'Flu Shipped'[Date Shipped],
CALCULATE(
COUNTROWS( DateTable ),
DATESBETWEEN ( DateTable[Date],  'Flu Shipped'[Due Date], 'Flu Shipped'[Date Shipped]),DateTable[DateIsWorkingDay]= True,
    ALL ( 'Flu Shipped' )
),

CALCULATE(
COUNTROWS( DateTable ),
DATESBETWEEN ( DateTable[Date], 'Flu Shipped'[Date Shipped], 'Flu Shipped'[Due Date]), DateTable[DateIsWorkingDay]=True,
    ALL ( 'Flu Shipped' )
) * -1)

Helpful resources

Announcements
March Fabric Community Update

Fabric Community Update - March 2024

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

Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.