Filtering is one of the most used feature in Excel. It is a quick way to take lots of data and narrow down to the subset we want.
Naturally, there are many powerful ways to work with filters. To name a few,
- Using CTRL+Shift+L shortcut to quickly turn on / off the filters
- Right clicking on a cell value and choosing filter > filter by selected cell’s value
- Using advanced filters to set up complex filtering conditions
But here is one common filtering scenario that is slow as snail.
Imagine you are looking at some sort of sales data (if you can’t imagine, look at the below demo).
Now, you want to filter this list for a combination like, gender=male, profession=self-employed, product category = chocolates and quantity = 1.
If you use the right click, filter > filter by selected value approach, this will take several clicks.
Wouldn’t it be cool if you can select the entire combination and say filter?
Unfortunately, no such feature exists in Excel.
But you are not aiming to be ordinary in Excel. You are aiming to be awesome in Excel. That means, you don’t take no for answer.
Fortunately, we can quickly write a VBA macro that filters a list by selection. So let’s do that. Here is what you will learn to create:

Filtering a table by selected combination of values using VBA
What we need to achieve?
Our goal is simple. User (that is you) selects a range of cells depicting the conditions for filtering. Something like this.
After selection, we fire up the filtering macro and instantly our list is filtered.
We can select a single-range or multiple cells (using CTRL+select technique)
Just to keep things simple, let’s assume the data is always in a table.
Algorithm / Steps for the VBA macro
Whenever you attempt to write VBA code, it is a good idea to start by writing down the steps in plain English. This is called as algorithm. By writing down the steps, we force our mind to think clearly about the problem at hand and come up with best possible solution.
Here are the steps for filtering the table by selected combination
- Make sure user has selected some values in a table
- Check if more than one row is selected. If so, exit as we don’t want to filter based OR conditions, we just want to filter based on AND conditions.
- For each cell in the selection
- Find out the corresponding column number
- Apply filtering on the table for corresponding column number with the cell’s value
- Repeat for next cell
- Done
VBA code – Filtering based on selected combination
Here is the VBA code for filtering based on selected combination. First examine the code. Then, we will understand key segments of it.
Sub combinationFilter()
Dim cell As Range, tableObj As ListObject, subSelection As Range
Dim filterCriteria() As String, filterFields() As Integer
Dim i As Integer
'If the selection is in a table and one row height
If Not Selection.ListObject Is Nothing And Selection.rows.Count = 1 Then
Set tableObj = ActiveSheet.ListObjects(Selection.ListObject.Name)
i = 1
ReDim filterCriteria(1 To Selection.Cells.Count) As String
ReDim filterFields(1 To Selection.Cells.Count) As Integer
' handle multi-selects
For Each subSelection In Selection.Areas
For Each cell In subSelection
filterCriteria(i) = cell.Text
filterFields(i) = cell.Column - tableObj.Range.Cells(1, 1).Column + 1
i = i + 1
Next cell
Next subSelection
With tableObj.Range
For i = 1 To UBound(filterCriteria)
.AutoFilter field:=filterFields(i), Criteria1:=filterCriteria(i)
Next i
End With
Set tableObj = Nothing
End If
End Sub
How does the combinationFilter() macro work?
Checking if selected cells are inside a table
We start by checking if the selection is inside a table by checking if the Selection.ListObject is not nothing. (Aside: there is no direct way to ask if there is a listobject. So we ask indirectly, by saying Not Selection.ListObject Is Nothing.)
Once we know that Selection is inside a table, we grab the table object and set it to the variable tableObj.
Finding out what to filter
To set filters on a table, we need to know the field number (ie column number inside the table) and filter criteria.
Filter criteria is denoted by cell values in the selection.
We are extracting filter criteria values & determining the column numbers for each of the selection’s cells using a simple For Each loop.
Setting up the filters
Once all the filter criteria are determined, we simply loop thru the criteria and set the filters on table using tableObj.Range.AutoFilter method.
How to use this macro for your data?
This macro is designed to work with any table. I have tested it in Excel 2010 & Excel 2013 and it seems to work alright.
To use it with your data, follow below steps.
- Open your personal macros file
- Copy the combinationFilter() macro and paste it in your Personal Macros workbook in a module
- Save and close personal macros file.
- Add this macro to Excel ribbon or quick access toolbar (QAT)
- To add to ribbon: Refer to below picture.

- To add to Quick Access Toolbar – click here for instructions.
- To add to ribbon: Refer to below picture.
- Once you select the combination to filter, click on the ribbon / QAT button.
- Done!
Download Selected Combination Filter Macro
Please click here to download the example workbook. Play with the macro to understand it better.
New to VBA? Learn how to exploit its awesome power
If you are new to VBA, you might find above example both awesome & hard to digest. But don’t worry. Start with this simple crash course on VBA. Check out more VBA examples. Very soon you will be automating parts of your work and impressing your boss. All the best.
Do you find the combination filter useful?
When I first thought about this macro, I feared the code might be too long or confusing. But I am happy with the outcome. It is a crisp, simple and powerful macro that I can use often when working with lots of data.
What about you? Do you find this macro useful? How are you planning to deploy it for your work situations. Let me know in the comments area.












12 Responses to “29 Excel Formula Tips for all Occasions [and proof that PHD readers truly rock]”
Some great contributions here.
Gotta love the Friday 13th formula 😀
Great tips from you all! Thanks a lot for sharing! bsamson, particularly you helped me on a terribly annoying task. 🙂
(BTW, Chandoo, it's not exactly "Find if a range is normally distributed" what my suggestion does. It checks if two proportions are statistically different. I probably gave you a bad explanation on twitter, but it'd be probably better if you fix it here... 🙂 )
Great compilation Chandoo
For the "Clean your text before you lookup"
=VLOOKUP(CLEAN(TRIM(E20)),F5:G18,2,0)
I would like to share a method to convert a number-stored-as-text before you lookup:
=VLOOKUP(E20+0,F5:G18,2,0)
@Peder, yeah, I loved that formula
@Aires: Sorry, I misunderstood your formula. Corrected the heading now.
@John.. that is a cool tip.
Hey Chandoo,
That p-value formula is really great for a statistics person like me.
What a p-value essentially is, is the probability that the results obtained from a statistical test aren't valid. So for example, if my p value is .05, there's a 5% probability that my results are wrong.
You can play with this if you install the Data Analysis Toolpak (which will perform some statistical tests for you AND provide the P Value.)
Let's say for example I've got two weeks of data (separated into columns) with the number of hours worked per day. I want to find out if the total number of hours I worked in week two were really all the different than week one.
Week1 Week2
10 11
12 9
9 10
7 8
5 8
Go to Data > Data Analysis > T-Test Assuming Unequal Variances > OK
In the Variable 1 Box, select the range of data for week 1.
In the Variable 2 Box, select the range of data for week 2.
Check "Labels"
In the Alpha box, select a value (in percentage terms) for how tolerant you are of error.
.05 is the general standard; that is to say I am willing to accept a 95% level of confidence that my result is accuarate.
Select a range output.
Excel calculates a number of results: Average (mean) for each week's data, etc.
You'll notice however that there are two P Values; one-tail and two-tail. (one tail tests are for > or .05), the number of hours I worked in week two is statistically equivalent to the number of hours I worked in week one.
So here’s a way you might want to use this. You put up a new entry on your blog. You think it’s the best entry ever! So you pull your webstats for this week and compare it to last week. You gather data for each week on the length of time a visitor spends on your website. The question you’re trying to prove statistically is whether there’s an average increase in the amount of time spent on your website this week as compared to last week (as a result of your fancy new blog post). You can run the same statistical test I illustrated above to find out. Incidentally, it matters very little to the stat test whether the quantity of visitors differs or not.
Anyhow, the Data Analysis toolpack doesn't perform a lot of stat tests that folks like me would like to have access to. In those cases I have to either use different software, or write some very complicated mathematical formulas. Having this p-value formula makes my life a LOT easier!
Thanks!
Eric~
Fantastic stuf..One line explanation is cool.
Thanks to all the contributors
OS
Take FirstName, MI, LastName in access (you can fix it to work in excel) capitalize first letter of each and lowercase the rest and add ". " if MI exists then same for last name:
Full Name: Format(Left([FirstName],1),">") & Format(Right([FirstName]),Len([FirstName])-1),"") & ". ","") & Format(Left([LastName],1),">") & Format(Right([LastName],Len([LastName])-1),"<")
I teach excel, access, etc etc for a living and i have my access students build this formula one step at a time from the inside out to show how formulas can be made even if it looks complicated. Yes I know I could just do IsNull([MI]) and reverse the order in the Iif() function but the point here is to nest as many functions as possible one by one (also I illustrate how it will fail without the Not() as it is)
Extract the month from a date
The easiest formula for this is =MONTH(a1)
It will return a 1 for January, 2 for February etc.
if in a column we write the value of total person for eg. 10 if we spent 1.33 paise each person then how we get total amount in next column and the result will in round form plzzzzz solve my problem sir................... thank u
@Anjali
If the value 10 is in B2 and 1.33 paise is in C2 the formula in D2 could be =B2*C2
If the values are a column of values you can copy the formula down by copy/paste or drag the small black handle at the bottom right corner of cell D2
kindly share with me new forumulas.
How to convert a figure like 870.70 into 870 but 871.70 into 880 using excel formula ? Please help.