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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
prabhatnath
Advocate III
Advocate III

Calculating Days and Hours between 2 DateTime columns excluding Saturday and Sunday

Hello,

I have one Incidents table with columns as below:
IncidentId, Title, Severity, Owner, CreatedDateTime, Status, ResolveDateTime, AcknowledgeDateTime.

The CreatedDateTime, ResolveDateTime, and AcknowledgeDateTime columns are of dateTime data type.

I want help to have:
1) Calculate Age of the Incident in Days based on CreatedDateTime and Current Date Time.
2) Calculate Average Acknowledge time in Days and Hours based on AcknowledgeDateTime and CreatedDateTime
3) Calculate Average Resolve time in Days and Hours based on ResolveDateTime and CreatedDateTime

All above calculattion must be excluding Saturday and Sunday while calculating.

Thanks,
Prabhat
 
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @prabhatnath ,

Based on my testing, please try the following methods:

1.Create the sample table.

vjiewumsft_0-1712636693692.png

2.Create the calculated column to calculate days.

 

Days = NETWORKDAYS('Table'[CreatedDateTime], TODAY()) - 1

 

3.Create the calculated column to calculate days and hours based on Acknowledge date and created date.

 

Acknowledge_aver = 
VAR days_ = NETWORKDAYS('Table'[CreatedDateTime], 'Table'[AcknowledgeDateTime]) - 1
VAR hour_ = HOUR('Table'[CreatedDateTime])
VAR end_hour = HOUR('Table'[AcknowledgeDateTime])

RETURN
IF(
        days_ > 0,
        (days_ - 1) * 24 + 24 - hour_ + end_hour,
        24-hour_
    )

//COUNTROWS(FILTER(CALENDAR('Table'[CreatedDateTime], 'Table'[AcknowledgeDateTime]), WEEKDAY([Date], 2) < 6))))))

 

4.Create the calculated column to calculate days and hours based on Resolve date and created date.

 

Resolve_aver = 
VAR days_ = NETWORKDAYS('Table'[CreatedDateTime], 'Table'[ResolveDateTime]) - 1
VAR hour_ = HOUR('Table'[CreatedDateTime])
VAR end_hour = HOUR('Table'[ResolveDateTime])

RETURN
IF(
        days_ > 0,
        (days_ - 1) * 24 + 24 - hour_ + end_hour,
        24 - hour_
    )

 

5.Drag the column into the table visual. The result is shown below.

vjiewumsft_1-1712636781891.png

Best Regards,

Wisdom Wu

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
Anonymous
Not applicable

Hi @prabhatnath ,

Based on my testing, please try the following methods:

1.Create the sample table.

vjiewumsft_0-1712636693692.png

2.Create the calculated column to calculate days.

 

Days = NETWORKDAYS('Table'[CreatedDateTime], TODAY()) - 1

 

3.Create the calculated column to calculate days and hours based on Acknowledge date and created date.

 

Acknowledge_aver = 
VAR days_ = NETWORKDAYS('Table'[CreatedDateTime], 'Table'[AcknowledgeDateTime]) - 1
VAR hour_ = HOUR('Table'[CreatedDateTime])
VAR end_hour = HOUR('Table'[AcknowledgeDateTime])

RETURN
IF(
        days_ > 0,
        (days_ - 1) * 24 + 24 - hour_ + end_hour,
        24-hour_
    )

//COUNTROWS(FILTER(CALENDAR('Table'[CreatedDateTime], 'Table'[AcknowledgeDateTime]), WEEKDAY([Date], 2) < 6))))))

 

4.Create the calculated column to calculate days and hours based on Resolve date and created date.

 

Resolve_aver = 
VAR days_ = NETWORKDAYS('Table'[CreatedDateTime], 'Table'[ResolveDateTime]) - 1
VAR hour_ = HOUR('Table'[CreatedDateTime])
VAR end_hour = HOUR('Table'[ResolveDateTime])

RETURN
IF(
        days_ > 0,
        (days_ - 1) * 24 + 24 - hour_ + end_hour,
        24 - hour_
    )

 

5.Drag the column into the table visual. The result is shown below.

vjiewumsft_1-1712636781891.png

Best Regards,

Wisdom Wu

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

amitchandak
Super User
Super User

@prabhatnath , For Networkdays , you can use networkdays function

 

Power BI - Business day with and without using DAX Function NETWORKDAYS: https://www.youtube.com/watch?v=Qs03ZZXXE_c
https://medium.com/@amitchandak/power-bi-dax-function-networkdays-5c8e4aca38c

 

 

For business hours use the blog from Matt -https://exceleratorbi.com.au/calculating-business-hours-using-dax/

 

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
ryan_mayu
Super User
Super User

could you pls provide some sample data and expected output?





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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