VBA - Identify dead stock

JetSetDrive

New Member
Joined
Jul 26, 2019
Messages
14
I need assistance writing a code for identifying items not being sold within the last three months.

The last sale dates are in column P,Q,R

This is the last sale date at each of our three locations

I need to identify which rows have not had a sale in the last 3 months and copy and paste all data from the row into a new tab called "Dead Stock"

The information has a header that also needs to be copied over

Thank you in advance
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Assuming that your data on the active sheet starts in cell A1, try this in a copy of your workbook.

Code:
Sub DeadStock()
  Dim wsOld As Worksheet, wsNew As Worksheet
  Dim rCrit As Range
  Dim lr As Long
  
  Set wsOld = ActiveSheet
  Sheets.Add(After:=wsOld).Name = "Dead Stock"
  Set wsNew = Sheets("Dead Stock")
  With wsOld
    lr = .Cells.Find(What:="*", LookIn:=xlValues, SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Set rCrit = .Range("A" & lr + 3).Resize(2)
    rCrit.Cells(2).Formula = "=MAX(P2:R2)<EDATE(TODAY(),-3)"
    .Range("A1").CurrentRegion.AdvancedFilter Action:=xlFilterCopy, CriteriaRange:=rCrit, CopyToRange:=wsNew.Range("A1"), Unique:=False
    rCrit.ClearContents
  End With
  wsNew.UsedRange.Columns.AutoFit
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,853
Members
452,361
Latest member
d3ad3y3

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