VBA Autofilter

Chris4564

New Member
Joined
Mar 13, 2019
Messages
3
Hi - hoping someone can help me, I have a macro which is meant to copy a set of data into an email for distribution, part of the macro applies a filter to a column containing completion dates. After I run the macro no data is shown on the screen but when you check the filter custom filter it has been applied, frustratingly if you click OK the data that should be shown appears! Below is a simplified version of the code which still causes the issue:

Code:
Sub Test()

Dim WeekC As Date
WeekC = "20/01/2019"
Sheets("a. Quote Progress").Range("B5:AC5").AutoFilter Field:=15, Criteria1:=">" & WeekC - 1, Criteria2:="<" & WeekC + 7
End Sub

This is now driving me crazy!
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
deleted by Yongle
 
Last edited:
Upvote 0
You have Field:=15. Since your filter range starts in column B, that would put the key range as column P. Is that the correct column to filter on?
 
Upvote 0
You have Field:=15. Since your filter range starts in column B, that would put the key range as column P. Is that the correct column to filter on?

Yes, if you check the filter after running the macro it's set and on the right column, there's just no data visable!
 
Upvote 0
Code:
Sub TestFilter()
   Dim WeekC As Date, Crit As [COLOR=#ff0000]Long[/COLOR]

   WeekC = [COLOR=#ff0000]DateSerial(2019, 1, 20)[/COLOR]
  [COLOR=#ff0000] Crit[/COLOR] = WeekC
   Sheets("a. Quote Progress").Range("B5:AC5").AutoFilter Field:=15, Criteria1:=">" & [COLOR=#ff0000]crit - 1[/COLOR], [COLOR=#008080]Operator:=xlAnd, [/COLOR]Criteria2:="<" & [COLOR=#ff0000]crit + 7[/COLOR]
End Sub

Date filters are frustrating for me because Excel speaks American!
The above method ensures that the criteria is a date that Excel is guaranteed to interpret correctly
 
Last edited:
Upvote 0
or with fewer steps

Code:
Sub TestFilter()
  Dim Crit As Long
  Crit = CLng(DateSerial(2019, 1, 20))
  Sheets("a. Quote Progress").Range("B5:AC5").AutoFilter Field:=15, Criteria1:=">" & Crit - 1, Operator:=xlAnd, Criteria2:="<" & Crit + 7
End Sub
 
Upvote 0
Or even this. The # symbols make the value a date literal.
Code:
Dim WeekC As Date
WeekC = #20/01/2019#
Sheets("a. Quote Progress").Range("B5:AC5").AutoFilter Field:=15, Criteria1:=">" & WeekC - 1, Criteria2:="<" & WeekC + 7
End Sub
 
Upvote 0
Thanks for the input, WeekC is actually from a data entered on a userform which changes what I can do slightly, although the below is messy it works so ill live with it for now!

Code:
WeekC = ReportWeek.WCDate.Value
Sheets("a. Quote Progress").Range("B5:AC5").AutoFilter Field:=15, Criteria1:=Array _
    (Format(WeekC, "\ dd\/mm\/yyyy\"), _
    Format(WeekC + 1, "\ dd\/mm\/yyyy\"), _
    Format(WeekC + 2, "\ dd\/mm\/yyyy\"), _
    Format(WeekC + 3, "\ dd\/mm\/yyyy\"), _
    Format(WeekC + 4, "\ dd\/mm\/yyyy\")), _
    Operator:=xlFilterValues
 
Upvote 0
Glad you foound a solution and thanks for the feedback,
regards, JLG
 
Upvote 0

Forum statistics

Threads
1,213,529
Messages
6,114,155
Members
448,554
Latest member
Gleisner2

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