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

Date for Next Wednesday

Written by Allen Wyatt (last updated July 23, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


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 (8623) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) 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

Changing the Number of Columns

If you need to change the number of columns used in a portion of your document, it's easy to do when you use the Columns ...

Discover More

Displaying Blanks when Summing to Zero

If you use fields to sum the information in your table columns, you might want to display a blank when the sum is zero. ...

Discover More

Extracting Proper Words

If you've got a list of potential words, and you want to know which of those potential words are real, you'll appreciate ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (menu)

Backwards Date Parsing

Enter information into a worksheet, and you come to anticipate (and count on) how Excel will interpret that information ...

Discover More

Calculating Time Differences between Two Machines

Want to know how much of a time difference there is between your machine and a different machine? This tip provides some ...

Discover More

Pulling All Fridays

It can be handy to know when specific weekdays occur within a range of dates. Figuring out this information, using ...

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}] (all 7 characters, in the sequence shown) 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 two more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.