OzGrid

Return Date of the First, or nth Day of Month

< Back to Search results

 Category: [Excel]  Demo Available 

Return Date of the First, or nth Day of Month

 

Got any Excel/VBA Questions? Free Excel Help

The Custom Function below can be used to return the date of the nth specified day of any given month.

It can be used in any cell like;

=nthDayOfMonth("sun","11/11/2005",2)

Where "Sun" is the day we need to return the date of the 2nd occurrence of Sunday in the Month November.

Syntax

=nthDayOfMonth(Which_Day,Which_Date,Occurence)

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

Occurence is the occurrence of Which_Day

To be able to use this custom function in a Workbook, you must first place the code below into a standard module.

  1. Open The Workbook.
  2. Go To Tools>Macro>Visual Basic Editor (Alt+F11).
  3. Then To Insert>Module.
  4. Paste In The Code.
  5. Click The Top Right X To Return To Excel.

The Code

Function NthDayOfMonth(Which_Day As String, Which_Date As String, Occurence As Byte) As Date

Dim i As Integer

Dim iDay As Integer

Dim iDaysInMonth As Integer

Dim FullDateNew As Date

Dim lCount As Long



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

 

      

    FullDateNew = DateSerial(Year(Which_Date), Month(Which_Date), 1)

   

    iDaysInMonth = Day(DateAdd("d", -1, DateSerial _
                (Year(Which_Date), Month(Which_Date) + 1, 1)))



    For i = 0 To iDaysInMonth

        If Weekday(FullDateNew + i) = iDay Then

            lCount = lCount + 1

        End If

        If lCount = Occurence Then

            NthDayOfMonth = FullDateNew + i

            Exit For

        End If

    Next i



End Function

Now simply enter the function into any cell as shown above.

 

See also:

Excel VBA Macro Codes Tips & Tricks
Excel Message Box (MsgBox) Function
Multi Select ListBox
Automatically Add Date, Time or Date & Time
Display Excel AutoFilter Criteria
Use AutoFilter in Excel VBA to Filter by Date & Time

 

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.

 


Gallery



stars (0 Reviews)