Open the table Calendar in design view, go to the field Calendar Date, and change Indexed from No to Yes (No Duplicates) and save it.
Add this code to your module:
Code:
Public Function GetProductionStartDate(NeededDays As Integer, FinishDate As Date) As Date
Dim db As Database
Dim CalendarRst As Recordset
Dim TotalDays As Integer
Dim cont As Boolean
If NeededDays <= 0 Then
MsgBox ("needed days must be at least 1")
Exit Function
End If
Set db = CurrentDb()
Set CalendarRst = db.OpenRecordset("Calendar")
CalendarRst.Index = "Calendar Date" 'unique index on Calendar Date
CalendarRst.Seek "=", FinishDate
If CalendarRst.NoMatch Then
MsgBox (Format(FinishDate, "m/d/yyyy") & " is not in the calendar table!")
Exit Function
End If
TotalDays = 0 'change initialized value to 1 if the finish date counts as one of the needed production dates
cont = True
Do While cont
CalendarRst.MovePrevious
If CalendarRst.BOF Then
MsgBox ("not enough entries in the calendar date table!")
Exit Function
End If
If CalendarRst![Working] Then
TotalDays = TotalDays + 1
End If 'else non-work days add zero to total days needed
If TotalDays = NeededDays Then
cont = False
End If
Loop
GetProductionStartDate = CalendarRst![Calendar Date]
CalendarRst.Close
db.Close
End Function
I tested this by adding the following field to the query qryMaster_BusinessDates:
Start_Date: GetProductionStartDate(20,#9/20/2018#)
Replace the constant 20 with the number of days you actually need, and replace the constant #9/20/2018# with the actual production end date.
When I ran the query, Start_Date returned the date 8/22/2018.
For a query that only returns five rows, it seems slow. Nevertheless, it still works.