Years in Which a Date Occurred on a Particular Day

by Allen Wyatt
(last updated May 19, 2018)

2

Harold is trying to devise a formula that will tell him the last five years in which a particular date (say, May 10) occurred on a particular day of the week (say, Thursday).

There are a number of ways you can go about determining this information. One simple way is to, in a new worksheet, enter the date you want tested (such as 5/10/18) into cell A1. Just below that, in cell A2, enter a date a year earlier: 5/10/17. Select these two cells and drag the fill handle downward for however many cells desired, and you end up with a column containing the date May 10 on descending years. Next, in cell B1 enter the following formula:

=WEEKDAY(A1)

Copy this formula down for as many rows as you have dates in column A. This returns a value, 1 through 7, representing the day of the week for the dates in column A. Since 1=Sunday, 2=Monday, etc., that means that any value of 5 would represent a Thursday. Thus, you could place this formula into cell C1 and copy it down:

=IF(B1=5,YEAR(A1),"")

This "calls out" the years in which the date in column A is a Thursday. You could, if you prefer, simply forego adding column C and, instead, use filtering to show only those dates where the value in column B is 5 (Thursday).

You can also use an array formula to find the information you desire. First, select five cells in any column you'd like. Then, type the following in the Formula bar:

=LARGE((WEEKDAY(DATE(ROW(1918:2018),5,10))=5)*ROW(1918:2018),ROW(1:5))

Enter the formula by pressing Ctrl+Shift+Enter. The result is that the five cells will contain the last five years in which May 10 was a Thursday. You could make the formula more versatile by replacing the key elements with named ranges, in this manner:

=LARGE((WEEKDAY(DATE(ROW(1918:2018),MO,DA))=DW)*ROW(1918:2018),ROW(1:5))

Now all you need to do is to create the named ranges MO (month), DA (day), and DW (day of week). As you change the values in these named ranges, the array formula updates the five cells to reflect the desired years.

A third way to find the information is to create a macro that asks for a starting date and a day of the week. The macro can then step backward a year at a time until it grabs five years that meet the criteria.

Sub CalcDates()
    Dim sTemp As String
    Dim dBegin As Date
    Dim dWork As Date
    Dim J As Integer
    Dim iDoW As Integer
    Dim iYears(5) As Integer

    sTemp = InputBox("Beginning Date?")
    dBegin = CDate(sTemp)
    If dBegin > 0 Then
        sTemp = InputBox("Day of Week?")
        sTemp = LCase(Trim(sTemp))
        iDoW = 0
        For J = 1 To 7
            If sTemp = LCase(WeekdayName(J)) Then iDoW = J
        Next J
        If iDoW > 0 Then
            dWork = dBegin
            J = 0
            While J < 5
                If Weekday(dWork) = iDoW Then
                    J = J + 1
                    iYears(J) = Year(dWork)
                End If
                dWork = DateAdd("yyyy", -1, dWork)
            Wend

            sTemp = "These are the previous five years in which "
            sTemp = sTemp & MonthName(Month(dBegin)) & " " & Day(dBegin)
            sTemp = sTemp & " falls on a " & WeekdayName(iDoW) & ":"
            sTemp = sTemp & vbCrLf & vbCrLf
            For J = 5 To 1 Step -1
                sTemp = sTemp & iYears(J) & vbCrLf
            Next J
            MsgBox sTemp
        End If
    End If
End Sub

When the macro finds the five years, it displays them in a message box.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13529) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365.

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

Replacing with Plain Text

When using Find and Replace, how your replacements are formatted will depend on how the text being replaced is formatted. ...

Discover More

Weird Mouse Shortcut

If you like to use the mouse in your worksheet navigation efforts, you'll want to pay attention to this tip. Here you ...

Discover More

Finding the Nth Occurrence of a Character

The FIND and SEARCH functions are great for finding the initial occurrence of a character in a text string, but what if ...

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)

Changing How Excel Determines which Year to Use

When you enter a date into a cell and you omit the year, Excel helpfully adds the current year to the date. If you want ...

Discover More

Calculating the First Business Day of the Month

Want to know which day of the month is the first business day? The easiest way to determine the date is to use the ...

Discover More

Pushing Dates Into Last Month

Excel is great when it comes to working with dates and times. You can even do math on dates. One such easy manipulation ...

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 two less than 5?

2018-05-21 10:33:13

Harlan

Array formulas can be very powerful, but sometimes you can change an array formula to a non-array formula by using a function that takes an array as an argument, such as sumproduct or index. I converted the last formula in this article to a non-array formula using index.
=LARGE(INDEX((WEEKDAY(DATE(ROW($1918:$2018),MO,DA))=DW)*ROW($1918:$2018),),ROW(1:1))
Place this formula in a cell, then copy down into 4 more cells (or as many as you need).


2018-05-19 11:50:39

Erik

Instead of the "=WEEKDAY(A1)" formula in the first solution, you could use "=TEXT(A1,"ddd")". The result will be Mon, Tue, Wed, etc. Use "dddd" instead of "ddd" and the result is the weekday name in full. Either way, you don't have to think about what number you want when you filter.


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.