![]() |
#1
|
|||
|
|||
![]() Hello, In my spreadsheet (in cell A4), I have the formula =TODAY(). In cell A3, the formula is: =A4-1. The formula in cell A3 works well Tue-Fri, but when I come into work on Monday, I need cell A3 to display a Friday date and not a Sunday date. Is there any way to modify this formula so it skips over weekends? Your help is greatly appreciated, Karen |
#2
|
||||
|
||||
![]()
For a dynamic formula that updates daily, you could use:
Quote:
Quote:
__________________
Cheers, Paul Edstein [Fmr MS MVP - Word] |
#3
|
|||
|
|||
![]()
Or in A3 use (assumed the worksheet is never used at weekends, and you have to cope with state holidays otherwise)
Code:
=TODAY() - IIF(WEEKDAY(TODAY(),2)=1,3,1) |
#4
|
|||
|
|||
![]() Quote:
Thank you so much for your help. If you have a chance, would you please explain this formula in layman's terms? Your help is greatly appreciated. Thank you, Karen |
#5
|
|||
|
|||
![]() Quote:
Also, I do need to deal with holidays. I'm not sure how to set up that hidden calendar. Your help is greatly appreciated. Thank you, Karen |
#6
|
|||
|
|||
![]() Quote:
For other workdays (from Tuesday to Friday, with weekday numbers from 2 to 5), the formula returns the date of previous workday (TODAY -1). As I declared in my precvious post, the formula in not meant to use at weekends. In case you want this formula to work when the workbook is opened at weekends (but ignoring holidays) too, you have to use instead Code:
=TODAY() - CHOOSE(WEEKDAY(TODAY(),2),3,1,1,1,1,1,2) Quote:
Add another column (e.g. column B with header "Weekday"), and fill it with weekday numbers using WEEKDAY() formula; Add another column (e.g. column C with header "Holiday"), and fill it with number 1 for every holiday in daterange of your table. When the date isn't a holiday, leave it empty, or enter 0; Add another column (e.g. column D with header "PreviousWD"). Based on info in columns B:C, fill this column with 0 when the date is workday and it is not a holiday. Otherwise enter, how many days back was last workday (1, or 2, or ... days). It is possible to create a formula for this column, but I'm afraid this will be too complex for you, and I don't have access to Excel currently, and even having it, the creating such formula will take hours for me too. Now either define this calendar table as Table with name like tCalendar, or select the whole datarange of created table, and define it as Name like nCalendar (I'll continue with defined Name below). On your original sheet, into cell A3 enter the formula like Code:
=(TODAY()-1) - VLOOKUP((TODAY()-1),nCalendar,4,0) After checking the formula for previous workday working, you can hide the sheet with calendar table you created. Last edited by ArviLaanemets; 11-22-2024 at 11:56 AM. |
#7
|
||||
|
||||
![]()
In the attached, formula in cell B4:
=WORKDAY(A4,-1,Holidays) You could have more control with =WORKDAY.INTL(A4,-1,1,Holidays) in cell B4 if WORKDAY.INTL is available to you in your version of Excel. Holidays is the name of a table containing a list of holiday dates. For demonstration purposes, in the attached: The date in cell A4 is not =TODAY() but fixed to today's date (22/Nov/2024) but this will still work if you do use =TODAY() Also, I've added a few more dates below cell A4 and used the same formulae in columns B & C. I've added conditional formatting to column A to highlight holiday dates and weekends so that you can confirm the formulae give the correct results. 2024-11-22_162713.jpg |
#8
|
||||
|
||||
![]() Quote:
When we divide a date by 7, the remainder tells us what day of the week it is. If the remainder is: 0 - the day is a Saturday 1 - the day is a Sunday 2 - the day is a Monday 3 - the day is a Tuesday 4 - the day is a Wednesday 5 - the day is a Thursday 6 - the day is a Friday The MOD function returns the remainder of a number and its divisor. Hence, if the remainder returned by MOD function of a date divided by 7 is 2, the date is a Monday. So: TODAY()-1 returns yesterday MOD(TODAY(),7)=2 is a True/False test for Monday and, if TRUE -(MOD(TODAY(),7)=2)*2 deduct another 2 days from today.
__________________
Cheers, Paul Edstein [Fmr MS MVP - Word] |
#9
|
|||
|
|||
![]()
Thank you so much for your detailed reply! Your explanation is incredibly helpful, and I truly appreciate the time and effort you put into this. People on this site are amazing!
Happy holidays! |
![]() |
|
![]() |
||||
Thread | Thread Starter | Forum | Replies | Last Post |
Date Formula Issue | matteu1 | Mail Merge | 1 | 07-23-2018 04:53 AM |
Formula for looking at 1 cell with a date and then comparing it to four date ranges | LearningMom | Excel | 3 | 10-27-2017 12:44 PM |
![]() |
caz46 | Excel | 3 | 04-15-2015 08:59 AM |
![]() |
MPAVLAS | Excel | 3 | 08-12-2010 10:04 PM |