Forum Discussion
Counting of business and non business hours white a ticket was open
- Oct 02, 2019
If add helper columns like this
not to harcode constants, the formula could be
=24*( IF( INT(Q2)-INT(P2)>2, NETWORKDAYS.INTL(P2+1,Q2-1,7),0 ) + IF( INT(Q2)=INT(P2), MIN(MOD(Q2,1),$AF$2)-MAX(MOD(P2,1),$AE$2), ($AF$2-MAX(MOD(P2,1),$AE$2))*(WEEKDAY(P2,15)>2) + MAX(MOD(Q2,1)-$AE$2,0)*(WEEKDAY(Q2,15)>2) ) )result in hours (e.g. 1.5 hour, not 01:30)
Hi Najat_abu_hamad,
You want to count business and non-business hours.
I have developed a formula according to the conditions you require, please check in the attached sheet and let me know to have detailed description, if it solves your problem.
Thank you for your effort...
the point that most of the tickets were open between two dates,i.e:severaldays and different time schedule,
here is the required task showing below and the attached file have the data you may need to understand the process:
calculate the number of business and non-business hours accoarding to the table on the attached screenshoot (plz,make it configurable, not hardcoded as the time scheduling table may change, whereby the sum of business and non business hours should equal the difference between columns Q-P
- SergeiBaklanOct 02, 2019Diamond Contributor
If add helper columns like this
not to harcode constants, the formula could be
=24*( IF( INT(Q2)-INT(P2)>2, NETWORKDAYS.INTL(P2+1,Q2-1,7),0 ) + IF( INT(Q2)=INT(P2), MIN(MOD(Q2,1),$AF$2)-MAX(MOD(P2,1),$AE$2), ($AF$2-MAX(MOD(P2,1),$AE$2))*(WEEKDAY(P2,15)>2) + MAX(MOD(Q2,1)-$AE$2,0)*(WEEKDAY(Q2,15)>2) ) )result in hours (e.g. 1.5 hour, not 01:30)
- Najat_abu_hamadOct 02, 2019Copper Contributor
Thanks a lot for your help,it is effective formula for the most of data but the problem now is when i tried to drag and drop the formula to the rest of data, in some cells it gives me #name! or #num! excel error as shown on the attached file, and on some cells like cell(Z3), the formula results ( in business hours> duration ), and that is not correct and therefore gives negative # of non business hours..
to solve the negativity problem i observed that this issue only happened when non business hours=0,so i can filter these cells and choose business hours = duration directly.
Thanks for your attention. I'm looking forward to your reply
- SergeiBaklanOct 02, 2019Diamond Contributor
Something strange, I opened the file you attached to the latest post and see no one #NAME! or #NUM! error. Calculations are also correct (at least Business Hours are less than Duration)
All negative results are -0.01 as at the bottom right of above screenshort. That's rounding error, you may entire formula for Non-Busiess hours as
=IF(<formula> <0, 0, <formula>)I recalculate the sheet, please check attached again.