Written by Allen Wyatt (last updated August 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
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, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Date for Next Wednesday.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Need to know how many days there are between two dates? It's easy to figure out—unless you need the figure in ...
Discover MoreIf you use Excel to track information based on dates, you may wonder how to get a sum for only certain dates that you ...
Discover MoreNeed to figure out if one date is between two other dates? There are a wide variety of formulaic approaches you could use ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments