VBA Filter

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
524
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!
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,231
Office Version
365
Platform
Windows
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
 

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
524
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?
 

My Aswer Is This

Well-known Member
Joined
Jul 5, 2014
Messages
16,278
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.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,231
Office Version
365
Platform
Windows
Which column are you looking to filter?
 

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
524
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.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,231
Office Version
365
Platform
Windows
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
 

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
524
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.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,231
Office Version
365
Platform
Windows
Glad to help & thanks for the feedback.
 

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
524
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
 

Forum statistics

Threads
1,082,045
Messages
5,362,862
Members
400,696
Latest member
Kclynn

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top