×

Filter Data With An Excel Table Read Into A VBA Array

By Chris Newman •  Updated: 06/19/14 •  4 min read
Filter Data With An Excel Table Read Into A VBA Array

What This VBA Code Does

Many times it is much easier to tweak VBA code through a spreadsheet versus changing the code itself in the VBE (Visual Basic Editor).  My favorite way to do this is by creating lists via Excel Tables.  The code below uses this concept and filters data based on what values are stored in the Filter On table (shown to the right).  This is a methodology I use very often, especially while creating a workbook for users whom do not understand how to modify VBA macros well.  This keeps the users away from my code (and possibly breaking it!) while letting them make changes to the functionality.  

Filter Data With An Excel Table Read Into A VBA Array
Sub Filter_Report()
'PURPOSE: Use a Table range to determine how data should be filtered
'SOURCE: www.TheSpreadsheetGuru.com

Dim Data_sht As Worksheet
Dim Settings_sht As Worksheet
Dim Table As ListObject
Dim myTable As ListObject
Dim myArray As Variant
Dim TempArray As Variant
Dim myAddress As String
Dim FilterColumn As Long

'Set paths for Sheets and Table variables
  Set Data_sht = ThisWorkbook.Worksheets(Sheet1.Name)
  Set Settings_sht = ThisWorkbook.Worksheets(Sheet2.Name)
  Set myTable = Settings_sht.ListObjects("Table1")

'Create Array List from Table
    TempArray = myTable.DataBodyRange
      'Convert from vertical to horizontal array list
        myArray = Application.Transpose(TempArray)

'Find Address of Data Needing Filtered
  myAddress = Data_sht.UsedRange.Address

'Which Column in Data Set to filter?
  FilterColumn = 1
  
'Filter Data
  Data_sht.Range(myAddress).AutoFilter Field:=FilterColumn, _
    Criteria1:=myArray, Operator:=xlFilterValues
    
'Scroll to Top of Data Worksheet
  Data_sht.Activate
  ActiveWindow.ScrollRow = 1
  
End Sub

Using VBA Code Found On The Internet

Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.

Getting Started Automating Excel

Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.

Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Keep Learning

Chris Newman

Chris Newman

Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.