Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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

Written by Allen Wyatt (last updated August 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


2

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)
=CEILING(A1-4,7)+4
=A1+6-MOD(A1+2,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 8/7/24 (a Wednesday), then each of these will return 8/7/24. However, if the date in A1 is 8/8/24 (a Thursday) then the formula returns 8/14/24.

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)

With so many options, which formula should you use? It is entirely up to you and your preferences. Most people would opt for the shortest formula that does the job, but you may want to use a longer one if it is easier for you (or whoever uses your workbook) to understand.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8625) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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

Opening an HTML Page in a Macro

Excel allows you to open HTML pages within the program, which is great for some purposes. What if you want to open a ...

Discover More

Formatting the Border of a Legend

When you create a chart, Excel often includes a legend with the chart. You can format several attributes of the legend's ...

Discover More

Preventing Jumbled Sorts

Click the Sort tool in Excel, and you may be surprised that the data in your worksheet is jumbled. In order to sort ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Calculating Future Workdays

Need to calculate the date that is a certain number of workdays in the future? You can do so using a couple of different ...

Discover More

Determining Month Names for a Range of Dates

Given a starting date and an ending date, you may want to generate the names of all the months between those two dates. ...

Discover More

Calculating Months for Billing Purposes

Different businesses have different ways to calculate elapsed time for billing purposes. Figuring out a formula that ...

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 9?

2024-08-12 07:32:51

RKEEVILL

IF THE DAY OF THE WEEK IS THE SAME AS THE START DATE DON'T USE -1 USE +1

=WORKDAY.INTL(A1+1,1,"1101111")if you're looking for the next Wednesday after the date in cell A1.


2024-08-12 07:27:33

RKEEVILL

this formula is far easier

=WORKDAY.INTL(A1-1,1,"1101111")if you're looking for the next Wednesday after the date in cell A1.

=WORKDAY.INTL(A1-1,3,"1101111") if you're looking for the 3rd Wednesday after the date in cell A1.


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.