VBA Filter

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
656
Hi,

Is there a way to define the Criteria1:=Array so that it shows all items except the ones you define? So how would i define the array if i wanted to show all values except Apple, Oranges, Pears?

Thanks!
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
The array would need to contain every value in the column, except those you want to be hidden.
Alternatively look at using an Advanced Filter
 
Upvote 0
I know the values that I always want to show, but the values in the column will always vary. If i make a list of those values, can I use that to define the array of what should be shown?
 
Upvote 0
I saw a post here last week asking nearly the same question and Peter gave an answer but it was a very long formula for just about 4 values to say <>John and <>Sam exc.

And that was using advanced filter.

Why not have a script copy all the rows for example that you do want to keep to another sheet.

Then an array can be written to copy rows with Bill and Sally and Joe in column C to a sheet named Me

But maybe that would not work for you.

But then maybe someone else here will have a answer.

I will watch and see and maybe learn how myself.
 
Upvote 0
Which column are you looking to filter?
 
Upvote 0
The column B has the data in it. I was hoping that I could use the data on sheet2 A5:A15 as the values to filter by. I can input those individually into the code, but thought it might be easier to define the range since it could be dynamic.
 
Upvote 0
How about
Code:
Sub FilterData()
   Dim cl As Range
   
   With CreateObject("scripting.dictionary")
      For Each cl In Range("B2", Range("B" & Rows.count).End(xlUp))
         .Item(cl.Value) = Empty
      Next cl
      For Each cl In Sheets("sheet2").Range("A5:A40")
         If .exists(cl.Value) Then .Remove cl.Value
      Next cl
      Range("B:B").AutoFilter 1, .keys, xlFilterValues
   End With
End Sub
 
Upvote 0
Fluff, you saved me again! I was playing around with that formula, but couldn't quite make it work. The AutoFilter line was the key! I was playing around to see if i could also flip it by changing .Remove to .Show...nope.
 
Upvote 0
Glad to help & thanks for the feedback.
 
Upvote 0
any ideas on why this Advanced Filter isn't working?

If have the Dim's and defined the worksheets earlier in the code.

Lastrow2 = wsF.Cells(wsF.Rows.Count, "A").End(xlUp).Row
LastrowF = wsF.Cells(wsF.Rows.Count, "A").End(xlUp).Row + 5


Dim FilterRange, PasteRange As Range
Set FilterRange = wsF.Range("A2" & Lastrow2)
Set PasteRange = wsF.Range("A" & LastrowF)

FilterRange.AdvancedFilter Action:=xlFilterCopy, CriteriaRange:=FilterRange, CopyToRange:=PasteRange, Unique:=True
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,259
Members
452,626
Latest member
huntinghunter

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