Please Note: This article is written for users of the following Microsoft Excel versions: 2007 and 2010. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Date for Next Wednesday.

Date for Next Wednesday

by Allen Wyatt
(last updated August 17, 2017)

7

Sam has a date in cell A1 and he would like to calculate the date of the following Wednesday in cell B1. He wonders what formula he should use for the calculation.

There are actually many formulas you can use, and the one you pick is pretty much up to you. Here is a good representative sampling of formulas you can use:

=IF(WEEKDAY(A1)<=4,A1+4-WEEKDAY(A1),A1+11-WEEKDAY(A1))
=A1+WEEKDAY(A1, 1)+CHOOSE(WEEKDAY(A1, 1), 2, 0, -2, -4, 1, -1, -3)
=A1+CHOOSE(WEEKDAY(A1),3,2,1,0,6,5,4)
=A1-MOD(WEEKDAY(A1)-5,7)+6
=A1+MOD(4-WEEKDAY(A1),7)

These formulas return a date that represents next Wednesday, provided that the date in cell A1 isn't a Wednesday to begin with. For instance, if the date in A1 is 5/26/10 (a Wednesday), then each of these will return 5/26/10. However, if the date is 5/27/10 then the formula returns 6/2/10.

If you want a formula that will return the next Wednesday even when the starting date is a Wednesday, then you should rely on a different formula. Choose from one of these:

=A1+IF(WEEKDAY(A1,1)=4,7,IF(WEEKDAY(A1,1)<4,4-WEEKDAY(A1,1),11-WEEKDAY(A1,1)))
=IF(WEEKDAY(A1)<4,A1+4-WEEKDAY(A1),A1+11-WEEKDAY(A1))
=IF(WEEKDAY(A1)=4,A1+7,A1+MOD(4-WEEKDAY(A1),7))
=A1+MOD(4-WEEKDAY(A1),7)+7*(0=MOD(4-WEEKDAY(A1),7))
=A1+7-MOD(4+WEEKDAY(A1,2),7)
=A1+4-WEEKDAY(A1)+IF(WEEKDAY(A1)<4,0,7)
=A1+CHOOSE(WEEKDAY(A1),3,2,1,7,6,5,4)
=A1+(7-MOD(WEEKDAY(A1,3)-2,7))
=A1+4-WEEKDAY(A1)+7*(WEEKDAY(A1)>=4)
=A1-MOD(WEEKDAY(A1)-4,7)+7
=A1+4+((WEEKDAY(A1)>=4)*7)-WEEKDAY(A1)
=A1+MOD(10-WEEKDAY(A1),7)+1
=A1+IF(WEEKDAY(A1) < 4,4,11)-WEEKDAY(A1)
=CEILING(A1-4,7)+4
=A1+6-MOD(A1+2,7)

It should be noted that the last two of these formulas works just fine on the PC but won't work as expected on the Mac. This is because the basis date used for date serial numbers is different on the Mac than it is on the PC, and thus the computations—which operate on the underlying serial numbers for the dates—return different values on each platform.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8625) applies to Microsoft Excel 2007 and 2010. You can find a version of this tip for the older menu interface of Excel here: Date for Next Wednesday.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Searching for Text With a Certain Format

The Find and Replace tool in Word is very powerful. You can use it to search not only for text but for the formatting ...

Discover More

Copying Worksheet Code Automatically

When creating a workbook to be used by others, you may want any worksheets they add to the workbook to contain some ...

Discover More

Offering Options in a Macro

It is often helpful to get user input within a macro. Here's a quick way to present some options and get the user's response.

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Including Weeks in Elapsed Time

When showing how much time has elapsed between two dates, it is sometimes helpful to express the result in terms of ...

Discover More

Converting UNIX Date/Time Stamps

If you import information generated on a UNIX system, you may need to figure out how to change the date/time stamps to ...

Discover More

Calculating Business Days

There are calendar days and then there are business days. Excel provides two functions (NETWORKDAYS and NETWORKDAYS.INTL) ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is seven less than 8?

2017-08-23 01:48:24

Agnius

Hi Alan,

You should probably also note that these formulas are constructed in such a way that it works with calendars where the first day of the week is Sunday, rather than Monday. The 4 in most cases should be changed into a 3 to work with the European way of starting a week on Mondays.


2017-08-17 04:04:38

Andries Olivier

Hi Allan

The last two formulas does not work =CEILING(A1-4,7)+4 ,=A1+6-MOD(A1+2,7) both return the same Wednesday date that appears in A1.

Regards

Andries


2017-08-17 03:57:53

Henk

Hi Allen,

What about?:

=IF(WEEKDAY(A1)=4,A1+7,A1+7-WEEKDAY(A1+7-4))

Regards


2017-08-17 03:30:58

Henk

Hi Allen,

All three of the following formulas give incorrect results:

=CEILING(A1-4,7)+4
=A1+6-MOD(A1+2,7)
=CEILING(A1-3,7)+4

Test for 15 and 16 Aug 2017, a Tuesday and a Wednesday.

Regards


2016-02-05 10:23:11

chris

How about a formula that gives me the next Thursday, however if today is a Thursday, show me today?

I have =Today() in A1

Thanks in anticipation


2014-03-01 07:18:13

Russell Gorton

I think that this formula:
=CEILING(A1-4,7)+4
should read:
=CEILING(A1-3,7)+4
if it is intended that a Wednesday starting date will return the next Wednesday.


2013-11-11 08:32:36

Bryan

You've given me 15 formulas to choose from (I'm not counting the first 5, since you already stated they don't solve the problem satement); which one should I use and why? Is there any reason to not use the shortest one (other than the fact that it doesn't seem to work as described)?


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.