March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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://drive.google.com/file/d/19YfqJi8mu_BSgjcZ1K9KHNNchKAKAInG/view?usp=sharing
Solved! Go to 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.
Hi Alpesh!
maybe this tool can help: https://docs.sqlbi.com/bravo/features/manage-dates/
Let me if it resolves your issue.
Regards,
RT
@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.
And i have the 'Calendar' Table where columns per country indicate if this particular Date is holiday or Weekend.
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!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |