Business days in Date_Add Interval
Hi,
I have a Beast Mode that calculates the estimated finish date of a process, depending on its type (new or renewal) and if it was started before or after 3 PM. My Beast Mode does this for calendar days, but I need the interval to be business days. We have a separate date table that flags each day for the next 5 years for weekday, business day, etc., but it is not currently joined to this dataset. The documentation I have seen so far talks about finding business days between 2 dates, but I need to add business days to one date. How can this be done?
My current Beast Mode is below:
CASE WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`,interval 2 day)) --New after 3 PM
WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`,interval 1 day)) --New before 3 PM
WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`,interval 4 day)) --Renew after 3 PM
WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`,interval 3 day)) --Renew before 3 PM
ELSE ' '
END
Thank you for your help,
Angela
Best Answer
-
Hi @AJ2020
MOD is the modulo operation. It simply says "divide these two numbers together and give me the remainder". In other words, how many left over days do I have after calculating the number of full weeks.
FLOOR just returns the whole number of a division operation without the fraction. I'm using it in two places. The first FLOOR([DAYS]/5) is telling me the number of whole "business" weeks I'm calculating to multiply by 7 to convert them to actual weeks. The other is just telling me if the start day is a Saturday (7) and if so subtract 1 for a one day weekend instead of 2.
It needed to add the number of business days remaining. My apologies. Currently it was only ever adding a single business day (+ 1) and not the day making up the partial week.
-- https://dojo.domo.com/discussion/52342/business-days-in-date-add-interval#latest -- Logic: -- Calculate the number of full business weeks -- Convert to actual 7 day work weeks -- Determine if adding the remining business days will go over a weekend -- if so, add 2 (or 1 if starting on a Saturday) to "jump" the weekend. -- Add the remaining business days. -- New after 3 PM CASE WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(2/5) * 7 + CASE WHEN MOD(2,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(2,5)) DAY)) -- New before 3 PM WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(1/5) * 7 + CASE WHEN MOD(1,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(1,5)) DAY)) -- Renew after 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(4/5) * 7 + CASE WHEN MOD(4,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(4,5)) DAY)) -- Renew before 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL -- Number of Full Weeks that make up the number of business days -> convert to actual 7 day weeks (FLOOR(3/5) * 7 + -- MOD tells us the remainder of business days which don't make up a full business week -- Does this go over a weekend? -- if so, add 2 (or 1 if starting on a Saturday) to "jump" the weekend. CASE WHEN MOD(3,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END -- Add the remaining business days + MOD(3,5)) DAY)) ELSE ' ' END
**Was this post helpful? Click Agree or Like below**
**Did this solve your problem? Accept it as a solution!**3
Answers
-
Hi @AJ2020
This was a fun question that I had to play around with. Currently you can't just say "add X business days" to the date_add function (though it'd be great). The following beast mode will add X number of business days to a date however it's not smart enough to exclude holidays.
Here's the basic version of it replace all instances of
6
with the number of business days :`dt` + INTERVAL (FLOOR(6/5) * 7 + CASE WHEN MOD(6,5) + DAYOFWEEK(`dt`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`dt`)/7) ELSE 0 END + 1) DAY
dt
is your date column.FLOOR(6/5) *7
Is determining the number of full weeks for the number of business days
CASE WHEN MOD(6,5) + DAYOFWEEK(`dt`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`dt`)/7) ELSE 0 END
Is determining if the partial week would overlap Saturday (7) / the weekend and then subtract a day if we're starting on Saturday (1 day weekend and not 2 day weekend)
And finally we add 1 to correctly offset the addition of the days.
This makes it a bit more complex logically but simpler in trying to calculate the number of actual days from the business days. You don't have to pre-calculate the number of actual days based on your business dates.
To put a nice bow on your request:
CASE WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`), INTERVAL (FLOOR(2/5) * 7 + CASE WHEN MOD(2,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY) --New after 3 PM WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(1/5) * 7 + CASE WHEN MOD(1,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --New before 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(4/5) * 7 + CASE WHEN MOD(4,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --Renew after 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(3/5) * 7 + CASE WHEN MOD(3,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --Renew before 3 PM ELSE ' ' END
**Was this post helpful? Click Agree or Like below**
**Did this solve your problem? Accept it as a solution!**2 -
@AJ2020 is this a duplicate post? or did my lengthy response not come through (sorry i thought i answered this last week).
EDIT:: totally misread your requirement.
Jae Wilson
Check out my 🎥 Domo Training YouTube Channel 👨💻
**Say "Thanks" by clicking the ❤️ in the post that helped you.
**Please mark the post that solves your problem by clicking on "Accept as Solution"2 -
Hi @GrantSmith ,
Thank you very much for the explanation! I had to read it a few times to digest it :)
When I use the formula you gave at the end, it passes the beast mode validation test, but when I refresh the page I get the error "An issue has occurred during processing. We are unable to complete the request at this time."
I noticed on your formula in the first "THEN" segment that there was a ")" after StartDateTime that did not exist on the other 3 WHENs. I tried both deleting it from the first instance and adding to the other 3, but neither worked and the formula validator said invalid both ways (and the calendar icon disappeared from the beast mode name). What could be the issue?
Thanks! Angela
0 -
Hi @jaeW_at_Onyx ,
Thanks! You answered a question of mine on another post. I am still trying to work through that one.
Thanks, Angela
0 -
Hi @AJ2020
I had a few errors in the prior beast mode one being the extra parenthesis but also missing the final parenthesis on the first case statement. Copy and paste will get you sometimes. Try this:
CASE WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(2/5) * 7 + CASE WHEN MOD(2,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --New after 3 PM WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(1/5) * 7 + CASE WHEN MOD(1,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --New before 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(4/5) * 7 + CASE WHEN MOD(4,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --Renew after 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(3/5) * 7 + CASE WHEN MOD(3,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + 1) DAY)) --Renew before 3 PM ELSE ' ' END
**Was this post helpful? Click Agree or Like below**
**Did this solve your problem? Accept it as a solution!**1 -
Hi @GrantSmith ,
Thanks for the eagle eyes! 😊 The formula is not quite jumping over the weekends. See chart below of some renewals where before 3 PM it should be 3 days & after 3 PM should be 4 days. I tried to play with the formula, but to be honest, I don't fully understand the FLOOR & MOD segments as they would be zero or fractions the way I currently understand them. I am a bit lost. How can the formula be adjusted to jump the weekend?
Thanks, Angela
0 -
Hi @AJ2020
MOD is the modulo operation. It simply says "divide these two numbers together and give me the remainder". In other words, how many left over days do I have after calculating the number of full weeks.
FLOOR just returns the whole number of a division operation without the fraction. I'm using it in two places. The first FLOOR([DAYS]/5) is telling me the number of whole "business" weeks I'm calculating to multiply by 7 to convert them to actual weeks. The other is just telling me if the start day is a Saturday (7) and if so subtract 1 for a one day weekend instead of 2.
It needed to add the number of business days remaining. My apologies. Currently it was only ever adding a single business day (+ 1) and not the day making up the partial week.
-- https://dojo.domo.com/discussion/52342/business-days-in-date-add-interval#latest -- Logic: -- Calculate the number of full business weeks -- Convert to actual 7 day work weeks -- Determine if adding the remining business days will go over a weekend -- if so, add 2 (or 1 if starting on a Saturday) to "jump" the weekend. -- Add the remaining business days. -- New after 3 PM CASE WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(2/5) * 7 + CASE WHEN MOD(2,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(2,5)) DAY)) -- New before 3 PM WHEN (`PurposeType`= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(1/5) * 7 + CASE WHEN MOD(1,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(1,5)) DAY)) -- Renew after 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)>=15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR(4/5) * 7 + CASE WHEN MOD(4,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD(4,5)) DAY)) -- Renew before 3 PM WHEN (`PurposeType`!= 'New') AND (HOUR(`StartDateTime`)<15) THEN DATE(DATE_ADD(`StartDateTime`, INTERVAL -- Number of Full Weeks that make up the number of business days -> convert to actual 7 day weeks (FLOOR(3/5) * 7 + -- MOD tells us the remainder of business days which don't make up a full business week -- Does this go over a weekend? -- if so, add 2 (or 1 if starting on a Saturday) to "jump" the weekend. CASE WHEN MOD(3,5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END -- Add the remaining business days + MOD(3,5)) DAY)) ELSE ' ' END
**Was this post helpful? Click Agree or Like below**
**Did this solve your problem? Accept it as a solution!**3 -
Hi @GrantSmith ,
Thank you for the excellent explanation! I wasn't understanding why to include the FLOOR when it was just a 0, but if the turn time goes over 4 days we will definitely need that portion. It is amazing the brain yoga you did to create this!
Thanks SO MUCH!
Angela
0 -
@AJ2020 You're welcome!
If you want to change the number of business days this is the template you'd can use. Just change [BUSINESS DAYS] to the number of business days you're wanting to add.
DATE(DATE_ADD(`StartDateTime`, INTERVAL (FLOOR([BUSINESS DAYS]/5) * 7 + CASE WHEN MOD([BUSINESS DAYS],5) + DAYOFWEEK(`StartDateTime`) >= 7 THEN 2 - FLOOR(DAYOFWEEK(`StartDateTime`)/7) ELSE 0 END + MOD([BUSINESS DAYS],5)) DAY)
**Was this post helpful? Click Agree or Like below**
**Did this solve your problem? Accept it as a solution!**2 -
0
-
@AJ2020 ,
to phrase, your question in plain English, is the problem you're trying to solve
"if the activity finished after 3pm THEN assign it to the next business day?"
if so then you can break the question into 2x parts
1) does the activity occur after 3pm?
CASE WHEN <activityOccursAfter3PM> Then <nextBusinessDay> ELSE <currentDate> END
2) how do i capture the next business day?
CASE WHEN <date is friday, saturday, or sunday> THEN <followingMonday> ELSE <currentDate + 1 day> END
3) how do i capture the day of the week? see if there's a function that will return dayOfWeek as a number between 1 and 7.
Good luck!
Jae Wilson
Check out my 🎥 Domo Training YouTube Channel 👨💻
**Say "Thanks" by clicking the ❤️ in the post that helped you.
**Please mark the post that solves your problem by clicking on "Accept as Solution"0
Categories
- All Categories
- 1.8K Product Ideas
- 1.8K Ideas Exchange
- 1.6K Connect
- 1.2K Connectors
- 300 Workbench
- 6 Cloud Amplifier
- 9 Federated
- 2.9K Transform
- 102 SQL DataFlows
- 626 Datasets
- 2.2K Magic ETL
- 3.9K Visualize
- 2.5K Charting
- 754 Beast Mode
- 61 App Studio
- 41 Variables
- 693 Automate
- 178 Apps
- 456 APIs & Domo Developer
- 49 Workflows
- 10 DomoAI
- 38 Predict
- 16 Jupyter Workspaces
- 22 R & Python Tiles
- 398 Distribute
- 115 Domo Everywhere
- 276 Scheduled Reports
- 7 Software Integrations
- 130 Manage
- 127 Governance & Security
- 8 Domo Community Gallery
- 38 Product Releases
- 11 Domo University
- 5.4K Community Forums
- 40 Getting Started
- 30 Community Member Introductions
- 110 Community Announcements
- 4.8K Archive