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
RT5
Regular Visitor

Calculating Elapsed Business Hours Using DAX

Hello!

 

Need some help to calculate Business Hours using Dax.

I found the solution i almost need here:

 

Calculating Elapsed Business Hours Using DAX Part 2 - Excelerator BI

 

Could you please help what should be updated in DAX to add Calculation of Business Hours for different countries with different Public Holidays, so for tickets issued in Spain for example were excluded spanish Public holidays, same for Portugal etc:

Business Hours Time
Start 09:00
End 18:00

Holiday 2021 Country
New Year’s Day Friday, 1 January 2021 Spain
Good Friday Friday, 2 April 2021 Spain
Labor Day Saturday, 1 May 2021 Spain

Freedom Day Sunday, 25 April 2021 Portugal
Republic Day Tuesday, 5 October 2021 Portugal

Thanks!!!

Pbix File and the holidays table are below:

 

https://docs.google.com/spreadsheets/d/19_9q1CUGqjWzhhDAMrnSKIRAlk4VIFOT/edit?usp=sharing&ouid=11561...

 

https://drive.google.com/file/d/19YfqJi8mu_BSgjcZ1K9KHNNchKAKAInG/view?usp=sharing

 

1 ACCEPTED SOLUTION

Hi @RT5 

 

Try this formula

Business Hours_2 =
VAR _Start = 'Incident Fact'[createdon]
VAR _End = 'Incident Fact'[Case_Solved]
VAR _Country = 'Incident Fact'[Country]
VAR _Workhours =
    SUMX (
        CALCULATETABLE (
            'Calendar',
            DATESBETWEEN ( 'Calendar'[Date], _Start, _End ),
            SWITCH (
                _Country,
                "Spain", 'Calendar'[Working Day Spain] = 1,
                "Portugal", 'Calendar'[Working Day Portugal] = 1
            )
        ),
        MAX ( MIN ( 'Calendar'[End], _End ) - MAX ( 'Calendar'[Start], _Start ), 0 ) * 24
    )
RETURN
    IF ( _Workhours, _Workhours, 0 )

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

6 REPLIES 6
RT5
Regular Visitor

Hi Alpesh!

 

maybe this tool can help: https://docs.sqlbi.com/bravo/features/manage-dates/

 

Let me if it resolves your issue.

 

Regards,

RT

amitchandak
Super User
Super User

@RT5 , you can refer this approch, but you need a calendar marked with holidays

 

https://exceleratorbi.com.au/calculating-business-hours-using-dax/

Hi Amit,

 

thanks for your response, i used the way you mentioned as well, it works, but the issue i face is how to include the following condition into DAX.

I have the 'Incident_Fact' Table with all the cases and there is column with countries in which the case was created.

RT5_0-1638801284591.png

 

And i have the 'Calendar' Table where columns per country indicate if this particular Date is holiday or Weekend. 

 

RT5_1-1638801284462.png

 

 

Business Hours_2 =
VAR _Start = 'Incident Fact'[createdon]
VAR _End = 'Incident Fact'[Case_Solved]
VAR _Workhours =
SUMX(
    CALCULATETABLE(
        'Calendar',
        DATESBETWEEN('Calendar'[Date],_Start,_End),
        'Calendar'[Working Day] = 1
    ),
MAX(MIN('Calendar'[End],_End) - MAX('Calendar'[Start],_Start),0) * 24
)
RETURN
IF(_Workhours,_Workhours,0)

 

 

I struggle to put this condition in the DAX above. It should be something like:
 
If 'Incident'[country_name] = "Spain" then use 'Calendar'[Working Day Spain] =1, 
If 'Incident'[country_name] = "Portugal" then use 'Calendar'[Working Day Portugal] =1 etc
 
Thanks

Hi @RT5 

 

Try this formula

Business Hours_2 =
VAR _Start = 'Incident Fact'[createdon]
VAR _End = 'Incident Fact'[Case_Solved]
VAR _Country = 'Incident Fact'[Country]
VAR _Workhours =
    SUMX (
        CALCULATETABLE (
            'Calendar',
            DATESBETWEEN ( 'Calendar'[Date], _Start, _End ),
            SWITCH (
                _Country,
                "Spain", 'Calendar'[Working Day Spain] = 1,
                "Portugal", 'Calendar'[Working Day Portugal] = 1
            )
        ),
        MAX ( MIN ( 'Calendar'[End], _End ) - MAX ( 'Calendar'[Start], _Start ), 0 ) * 24
    )
RETURN
    IF ( _Workhours, _Workhours, 0 )

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Hi, I know this is an old thread, but how could the same be modified for every country, where most countries have different start and end times and holidays?

It works, great. Thanks for help!

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.