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: Pulling All Fridays.
Written by Allen Wyatt (last updated January 15, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
When developing a worksheet to track business information, you may have a need to determine all the Fridays in a range of dates. The best way to do this depends on the data in your worksheet and the way in which you want results displayed.
If you have a list of dates in a column, you can use several different worksheet functions to determine whether those dates are Fridays or not. The WEEKDAY function returns a number, 1 through 7, depending on the weekday of the date used as an argument:
=WEEKDAY(A2)
This usage returns the number 6 if the date in A2 is a Friday. If this formula is copied down next to a column of dates, you could then use the AutoFilter feature of Excel to show only those dates where the weekday is 6 (Friday).
You could also use the conditional formatting feature of Excel to simply highlight all the Fridays in a list of dates. Follow these steps:
Figure 1. The Conditional Formatting dialog box.
=WEEKDAY(A2)=6
If you want to determine a series of Fridays based on a beginning and ending date, you can set up a series of formulas to figure them out. Assuming that the beginning date is in A2 and the ending date is in A3, you can use the following formula to figure out the date of the first Friday:
=IF(A2+IF(WEEKDAY(A2)<=6,6-WEEKDAY(A2),6)>A3, "",A2+IF(WEEKDAY(A2)<=6,6-WEEKDAY(A2),6))
If you place this formula in cell C2 and then format it as a date, you can use the following formula to determine the next Friday in the range:
=IF(C2="","",IF(C2+7>$A$3,"",C2+7))
If you copy this formula down for a bunch of cells, you end up with a list of Fridays between whatever range of dates is specified by A2 and A3.
If you actually want to "pull" Fridays in a specific date range, then you will need to use a macro. There are several ways you can go about this. This simple macro will examine all the dates in the range A2:A24. If they are Fridays, then the date is copied into column C, beginning at C2. The result, of course, is that the list starting at C2 will only contain dates that are Fridays.
Sub PullFridays1() Dim dat As Range Dim c As Range Dim rw As Integer Set dat = ActiveSheet.Range("A2:A24") rw = 2 For Each c In dat If Weekday(c) = vbFriday Then Cells(rw, 3).Value = Format(c) rw = rw + 1 End If Next End Sub
If desired, you can change the range examined by the macro simply by changing the A2:A24 reference, and you can change where the dates are written by changing the value of rw (the row) and the value 3 (the column) in the Cells function.
If you would rather work with a beginning date and an ending date, you can modify the macro so that it will step through the dates. The following macro assumes that the beginning date is in cell A2 and the ending date is in cell A3.
Sub PullFridays2() Dim dStart As Date Dim dEnd As Date Dim rw As Integer dStart = Range("A2").Value dEnd = Range("A3").Value rw = 2 While dStart < dEnd If Weekday(dStart) = vbFriday Then Cells(rw, 3).Value = dStart Cells(rw, 3).NumberFormat = "m/d/yyyy" rw = rw + 1 End If dStart = dStart + 1 Wend End Sub
The macro still pulls the Fridays from the range and places them into a list starting at C2.
Another macro approach is to create a user-defined function that returns specific Fridays within a range. The following does just that:
Function PullFridays3(dStartDate As Date, _ dEndDate As Date, _ iIndex As Integer) Dim iMaxDays As Integer Dim dFirstday As Date Application.Volatile If dStartDate > dEndDate Then PullFridays3 = CVErr(xlErrNum) Exit Function End If dFirstday = vbFriday - Weekday(dStartDate) + dStartDate If dFirstday < dStartDate Then dFirstday = dFirstday + 7 iMaxDays = Int((dEndDate - dFirstday) / 7) + 1 PullFridays3 = "" If iIndex = 0 Then PullFridays3 = iMaxDays ElseIf iIndex <= iMaxDays Then PullFridays3 = dFirstday + (iIndex - 1) * 7 End If End Function
You use this function in a cell in your worksheet in the following manner:
=PULLFRIDAYS3(A2,A3,1)
The first argument for the function is the starting date and the second is the ending date. The third argument indicates which Friday you want returned from within the specified range. If you use 1, you get the first Friday, 2 returns the second Friday, etc. If you use a 0 for the third argument, then the function returns the number of Fridays in the specified range. If the specified beginning date is greater than the ending date, then the function returns a #NUM error.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2930) 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: Pulling All Fridays.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Excel allows you to perform math using times as operands. If you subtract a later time from an earlier time, you should ...
Discover MoreDoing math with dates is easy in Excel. Doing math with old dates, such as those you routinely encounter in genealogy, is ...
Discover MoreWhen working with dates, it is often helpful to be able to calculate some date in the future based on a starting date. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments