Got any Excel/VBA Questions? Free Excel Help
Return Last Chosen Day of Given Month.
The Custom Function below can be used to return the last specified day of any given month.
It can be used in any cell like;
=LastDayOfMonth("Mon","10/10/2005")
Where "Mon" is the day we need to return the date of the last Monday in the Month October.
Syntax
=LastDayOfMonth(Which_Day,Which_Date)
Which_Day is a text abbreviation on any day, e.g. "Sat"
Which_Date is a text representation of any valid date, e.g. "10-Oct-2005", "10-10-2005" etc
To be able to use this custom function in a Workbook, you must first place the code below into a standard module.
'The Code
Function LastDayOfMonth(Which_Day As String, Which_Date As String) As Date Dim i As Integer Dim iDay As Integer Dim iDaysInMonth As Integer Dim FullDateNew As Date Which_Date = CDate(Which_Date) Select Case UCase(Which_Day) Case "SUN" iDay = 1 Case "MON" iDay = 2 Case "TUE" iDay = 3 Case "WED" iDay = 4 Case "THU" iDay = 5 Case "FRI" iDay = 6 Case "SAT" iDay = 7 End Select iDaysInMonth = Day(DateAdd("d", -1, DateSerial _ (Year(Which_Date), Month(Which_Date) + 1, 1))) FullDateNew = DateSerial(Year(Which_Date), Month(Which_Date), iDaysInMonth) For i = 0 To iDaysInMonth If Weekday(FullDateNew - i) = iDay Then LastDayOfMonth = FullDateNew - i Exit For End If Next i End Function
Now simply enter the function into any cell as shown above.
See also Index to Excel VBA Code and Index to Excel Freebies and Lesson 1 - Excel Fundamentals and Index to how to… providing a range of solutions.
Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.