Display Workdays ONLY

BillTony

Board Regular
Joined
May 3, 2017
Messages
70
Hi there,

The code below displays / outputs a list all dates between a specified starting and ending date input by the user.

However, I'm having a bit of trouble only listing WORKDAYS (Monday through Friday).

An added BONUS would be to also eliminate Holidays from the list.

Any advice or assistance would be GREATLY appreciated!

Code:
Sub Date_Generator()
'Create some VARIABLES.
    Dim Start_Date As Date
    Dim End_Date As Date
    Dim Next_Date As Date
'Set the Column Width.
    Columns("A:C").ColumnWidth = 20
'Assign some VALUES.
    Start_Date = Range("B1").Value
    End_Date = Range("B2").Value
    Next_Date = Start_Date
    
'Set the OUTPUT Destination.
    Range("C1").Select
    
'Set the PARAMETERS of the DATE RANGE.
    Do Until Next_Date >= End_Date
    
    ActiveCell.Value = Next_Date
    ActiveCell.Offset(1, 0).Select
    Next_Date = Next_Date + 1
    
'Tell it to INCREMENT
    Loop
    
    
End Sub
 
Last edited:

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Hi, here is some code you can try:

Code:
Sub Date_Generator()
'Create some VARIABLES.
    Dim Start_Date As Date
    Dim End_Date As Date
    Dim Total_Workdays As Long
'Set the Column Width.
    Columns("A:C").ColumnWidth = 20
'Assign some VALUES.
    Start_Date = Range("B1").Value
    End_Date = Range("B2").Value
    Total_Workdays = Application.NetworkDays(Start_Date, End_Date, Range("Holidays"))
'OUTPUT the results.
    With Range("C1").Resize(Total_Workdays)
        .Cells = Evaluate("choose({1},workday(" & CLng(Start_Date) - 1 & ",row(1:" & Total_Workdays & "), holidays))")
    End With
End Sub

You need to have a named range called holidays that refers to a list of holiday dates.
 
Upvote 0
Try this
Create a range containing your holiday dates and amend Sheets("Sheet5").Range("A1:A8")


Code:
Sub Date_Generator()
'Create some VARIABLES.
    Dim Start_Date As Date
    Dim End_Date As Date
    Dim Next_Date As Date
    Dim w As Long
    Dim Cel As Range
'Set the Column Width.
    Columns("A:C").ColumnWidth = 20
'Assign some VALUES.
    Start_Date = Range("B1").Value
    End_Date = Range("B2").Value
    Next_Date = Start_Date
    
'Set the OUTPUT Destination.
    Range("C1").Select
    
'Set the PARAMETERS of the DATE RANGE.
    Do Until Next_Date >= End_Date
        For Each Cel In [COLOR=#ff0000]Sheets("Sheet5").Range("A1:A8")[/COLOR]
            If Next_Date = Cel Then Next_Date = Next_Date + 1
        Next Cel
        w = Weekday(Next_Date)
        If w > 1 And w < 7 Then
            ActiveCell.Value = Next_Date
            ActiveCell.Offset(1, 0).Select
        End If
        Next_Date = Next_Date + 1
    
'Tell it to INCREMENT
    Loop
    
End Sub
 
Upvote 0
Try this:
This does not eliminate Holidays.
Code:
Sub Date_Generator()
    'Modified  3/7/2019  8:40:37 AM  EST
Application.ScreenUpdating = False
    Dim Start_Date As Date
    Dim DD As Long
    Dim x As Long
    Dim ans As String
    x = 0
    Dim End_Date As Date
    Dim Next_Date As Date
'Set the Column Width.
Columns("A:C").ColumnWidth = 20
    Start_Date = Range("B1").Value
    End_Date = Range("B2").Value
    Next_Date = Start_Date
    ans = DateDiff("d", Start_Date, End_Date)
    
        For i = 1 To ans + 1
            DD = Weekday(DateAdd("d", i - 1, Start_Date))
                If DD <> 7 And DD <> 1 Then
                x = x + 1
                Cells(x, "C").Value = DateAdd("d", i - 1, Start_Date)
                End If
        Next
    Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,976
Messages
6,122,539
Members
449,088
Latest member
RandomExceller01

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top