How can I create a code to calculate first day in the month taking bank holidays away?

Eric Penfold

Active Member
Joined
Nov 19, 2021
Messages
424
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
Using code below as basis?

VBA Code:
Option Explicit

Sub FillDates()

Dim wb As Workbook
Dim ws As Worksheet
Dim FCell As Range
Dim LCell As Range
Dim LRow   As Long

Set wb = Workbooks("DailyMail.xlsx")
Set ws = wb.Worksheets("Daily Mail Update")
Set FCell = ws.Range("A2")
Set LCell = ws.Range("A2" & LRow)
LRow = ws.Cells(Rows.Count, 1).End(xlUp).Row

If Not Date = Application.WorkDay(DateSerial(Year(Date), Month(Date), 0), 1) Or _
    Date = Application.WorkDay(DateSerial(Year(Date), Month(Date), 0), 2) Then
    
FCell.Clear

FCell = Evaluate("Workday(EOMonth(Now(),-1),1)")
   
With FCell
    .HorizontalAlignment = xlCenter
    .NumberFormat = ("dd/mm/yy")
End With

End If

End Sub
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
First, there is a function that does that, do you insist on code?
Second, you will need a list of dates for the holidays.
 
Upvote 0
You still need a list with the holidays dates.
 
Upvote 0
Assuming:
  • you want to fill all non-empty cells in column A with the first working day of the current month
  • you have a list of dates with the Bank Holidays in BH1:BH10 for example (you can change this in the code)
Try this:
VBA Code:
Sub FillDates()
    Dim wb As Workbook
    Dim ws As Worksheet
    Dim FCell As Range
    Dim LRow   As Long

    Set wb = ActiveWorkbook ' Workbooks("DailyMail.xlsx")
    Set ws = ActiveSheet 'wb.Worksheets("Daily Mail Update")
    LRow = ws.Cells(Rows.Count, 1).End(xlUp).Row
    Set FCell = ws.Range("A2:A" & LRow)
    With FCell
        .Value = FirstWorkDayOfMonth(Date, ws.Range("BH1:BH10"))
        .HorizontalAlignment = xlCenter
        .NumberFormat = ("dd/mm/yy")
    End With
    Set wb = Nothing
    Set ws = Nothing
    Set FCell = Nothing
End Sub

Function FirstWorkDayOfMonth(ByVal xDate As Date, Optional ByRef BankHolidays As Range) As Date
    With Application.WorksheetFunction
        FirstWorkDayOfMonth = .WorkDay(.EoMonth(xDate, -1), 1, BankHolidays)
    End With
End Function
There is another function you can use WorkDay_Intl - it allows some control on the weekend days.
 
Upvote 0
Assuming:
  • you have Dates in the non-empty cells in column A, but you want to replace them with the first working day of their month
  • you have a list of dates with the Bank Holidays in BH1:BH10 for example (you can change this in the code)
Try this:
VBA Code:
Sub FillDates2()
    Dim wb As Workbook
    Dim ws As Worksheet
    Dim FCell As Range, cc As Range
    Dim LRow   As Long, x As Date
    Dim bhRange As Range

    Set wb = ActiveWorkbook ' Workbooks("DailyMail.xlsx")
    Set ws = ActiveSheet 'wb.Worksheets("Daily Mail Update")
    LRow = ws.Cells(Rows.Count, 1).End(xlUp).Row
    Set FCell = ws.Range("A2:A" & LRow)
    Set bhRange = ws.Range("BH1:BH10")
    
    For Each cc In FCell.Cells
        If Not IsDate(cc.Value) Then
            cc.Clear
        Else
            x = cc.Value
            cc.Value = FirstWorkDayOfMonth(Date, bhRange)
            cc.HorizontalAlignment = xlCenter
            cc.NumberFormat = ("dd/mm/yy")
        End If
    Next cc
    Set wb = Nothing
    Set ws = Nothing
    Set FCell = Nothing
    Set cc = Nothing
    Set bhRange = Nothing
End Sub

Function FirstWorkDayOfMonth(ByVal xDate As Date, Optional ByRef BankHolidays As Range) As Date
    With Application.WorksheetFunction
        FirstWorkDayOfMonth = .WorkDay(.EoMonth(xDate, -1), 1, BankHolidays)
    End With
End Function
 
Upvote 0

Forum statistics

Threads
1,215,198
Messages
6,123,593
Members
449,109
Latest member
Sebas8956

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