First Monday after previous 6th April

CookieMonster76

Board Regular
Joined
Apr 30, 2015
Messages
201
Hi

I have a date in cell A1, and I need cell C1 to give me return the first Monday after the previous 5th April.

For example, if the date in A1 is 13 April 2024, cell C1 would return 8 April 2024

If the date in A1 is 4 April 2024, cell C1 would return 10 April 2023

Thanks

Paul
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Please update your profile to reflect your version of Excel. I have provided a solution for older versions and also for new versions supporting the LET function.


Cell Formulas
RangeFormula
A2,A4A2=A1+1
B1:B2B1=DATE(YEAR(A1)-IF(A1<DATE(YEAR(A1),4,5),1,0),4,5)+7-WEEKDAY(DATE(YEAR(A1)-IF(A1<DATE(YEAR(A1),4,5),1,0),4,5),3)
B3:B4B3=LET(Yr, YEAR(A3),Dt,DATE(Yr-IF(A3<DATE(Yr,4,5),1,0),4,5),Dt+7-WEEKDAY(Dt,3))
 
Upvote 0
If you have a current version of excel you may use:
VBA Code:
=LET(a,DATE(YEAR(A1),4,5),b,IF(A1>=a,a,DATE(YEAR(A1)-1,4,5)),b+7-WEEKDAY(b,3))

The same in old Excel:
VBA Code:
=IF(A1>=DATE(YEAR(A1),4,5),DATE(YEAR(A1),4,5),DATE(YEAR(A1)-1,4,5))+7-WEEKDAY(IF(A1>=DATE(YEAR(A1),4,5),DATE(YEAR(A1),4,5),DATE(YEAR(A1)-1,4,5)),3)
 
Upvote 0
Is there an echo in here? :)
The posts are literally one minute apart! That happens to me quite often too, people often post in the time it takes me to test and type up my solution (dang my slow, poor typing skills!).

I always say if there are two nearly identical replies, that suggests that it is probably a very good answer (that two different people came up with similar solutions).
 
Upvote 0
Hi Jeff,

I shall probably limit myself to LET version :-D
I'd probably publish first by some seconds or a minute then 8-)

Nice to notice is that we both used weekday(x,3)

Have a good afrenoon (late afternoon here, in CET = GMT+1 and I think early afternoon in VA :-)).
 
Upvote 0
[off topic]
Well, I think* it's GMT-5, so at the moment in the middle of the night (or if yoy are jamming 🎸with nice band - just late evening :-P)
*) I've been nearby your place driving earlier this year on a way from Skyline Caverns to Washington, DC
[/off topic]

Anyway @CookieMonster76 (Paul) was seen on the forum an hour after answers were published. So probably has seen the answers. Let's wait for his reaction
 
Upvote 0
Or try this:

=LET(Yr, YEAR(A1+271)-1,WORKDAY.INTL(DATE(Yr,4,5),1,"0111111"))
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top