Written by Allen Wyatt (last updated January 16, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Do you keep track of information based on week-ending dates? Many businesses do, and therefore need a quick way to calculate the week-ending dates for the complete year. The dates could be easily calculated with a macro, but you can do it just as easily with formulas.
There are two formulas you can use in order to calculate your week-ending dates. Let's assume, for the sake of this example, that your year is stored in cell A1. (Remember: This is a year in A1 not a date.) You could then figure out the first Saturday of the year by using this formula in cell A3:
=DATE(A1,1,1)+7-WEEKDAY(DATE(A1,1,1))
This works because the WEEKDAY function returns a value of 1 (Sunday) through 7 (Saturday) for any date. If you subtract that value from 7, then you have a value of 6 (Sunday) through 0 (Saturday). When you add that value to the DATE value for January 1 of the year, you end up with the first Saturday of the year.
If you prefer to have your weeks end on Fridays, then the formula needs to change a bit:
=DATE(A1,1,1)+7-(WEEKDAY(DATE(A1,1,1)+1))
Finally, if you prefer to have your weeks end on Sundays, then the formula needs to be like this one:
=DATE(A1,1,1)+7-WEEKDAY(DATE(A1,1,1),2)
This formula uses a parameter for the WEEKDAY function that calculates weekdays that range from 1 (Monday) through 7 (Sunday).
Once you have the first week-ending date for the year (in A3, remember?), then you can calculate the rest of the week-ending dates for the year. Place the following formula in cell A4:
=IF(YEAR(A3+7)=$A$1,A3+7,"")
This checks to see if one week past the previous date is still in the year. If it is, then the new date is returned. If it isn't, then an empty string is returned. If you copy this formula from A4 down through A55, then you will have all the desired week-ending dates for the year. With the formulas in place, simply change the year in cell A1 to see how the dates change.
The range A3:A55 provides room for 53 week-ending dates, which is possible for any given year. Because you used the IF statement in the formula in cells A4:A55, then the very last value (A55) will be blank if there were only 52 week-ending dates for the year.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10481) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Calculating Week-Ending Dates.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
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 MoreCalculating a retirement date can be as simple as doing some date math to see when a person reaches a certain age. ...
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 MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-08-29 12:54:05
Sub GetSundays()
Dim d1 As Date, d2 As Date, dTemp As Date
Dim j
d1 = #8/2/2020#
d2 = #12/6/2020#
j = 1
dTemp = d1
Do Until dTemp = d2 + 1
If Weekday(dTemp) = 1 Then
Cells(j, 3) = dTemp
j = j + 1
dTemp = dTemp + 1
Else
dTemp = dTemp + 1
End If
Loop
End Sub
2020-08-28 04:15:54
Renjith EV
Sir,
My doubt is
Two dates are given, Egg; 01/08/2020 and 12/08/2020
between that dates,whether there is Sunday?
If Sunday is there, then display the date of that Sunday.
Kindly provide one solution
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