Not sure if this is what you want or if it will work with your problem but give it a go.
Insert this into a module on the workbook you are try to do your calculation.
Public Function WhichDay(MyAmount As Range, DateRange As Range, AmountRange As Range)
Dim Dates() As Date
Dim DateCount, Counter As Integer
Dim AmountLeft As Long
Counter = 0
AmountLeft = MyAmount.Value
For Each c In AmountRange
AmountLeft = AmountLeft - c.Value
If AmountLeft > 0 Then Counter = Counter + 1
Next
DateCount = 0
For Each c In DateRange
DateCount = DateCount + 1
ReDim Preserve Dates(DateCount)
Dates(DateCount) = c.Value
Next
If Counter + 1 > UBound(Dates()) Then
WhichDay = "Still " & AmountLeft & " Left"
Else
WhichDay = Dates(Counter + 1)
End If
End Function
This is a user defined function and it will appear in the Function list in Excel.
You need to pass it the cell with the Opening Inventory amount. The excel range of dates. Excel range with the daily usage.
It will then return the date that the Product will run out.
Example:
Column A Column B Column C
01/01/01 500 830
02/01/01 100
03/01/01 200
04/01/01 10
05/01/01 20
06/01/01 50
07/01/01 90
type in formula =WhichDay(C1,A1:A7,B1:B7)
this would then return 05/01/01 because that is the day that the stock runs out. (830-500-100-200-10-20=0)