How to use the FILTER function
The FILTER function lets you extract values/rows based on a condition or criteria. It is in the Lookup and reference category and is only available to Excel 365 subscribers.
What's on this page
- FILTER Function Syntax
- FILTER Function Arguments
- FILTER Function example
- Filter values based on a condition
- Why does the FILTER function return a #NAME? error?
- Is the FILTER function available for Excel versions 2003, 2007, 2010, 2013, 2016, and 2019?
- The FILTER function returns a #SPILL! error, why?
- Why does the FILTER function return a #CALC! error?
- Can I use the FILTER function with an Excel Table and structured references?
- Can the FILTER function handle error values?
- Is the FILTER function case sensitive?
- Filter values based on a condition - case sensitive
- Filter values if not equal to
- Filter values if smaller than
- Filter values if larger than
- Filter values if contains
- Filter values if not contain
- Filter values that begin with
- Filter values that end with
- Filter values based on a condition sorted from A to Z
- Filter values based on criteria
- Filter values based on a condition per column - AND logic
- Filter values based on a condition per column - OR logic
- Filter function - #CALC! error returns [if_empty] argument
- Extract filtered values (Link)
- Get Excel file
1. FILTER Function Syntax
FILTER(array, include, [if_empty])
2. FILTER Function Arguments
Argument | Text |
array | Required. Cell range or array. |
include | Required. An array containing True or False that match the rows and columns of the array argument. |
[if_empty] | Optional. The FILTER function returns #CALC! if the result is empty. [if_empty] is a value you define to avoid the #CALC! error. |
3. FILTER Function example
The image above shows a regular formula in cell D3:
The formula above filters the data set in cell range C3:C7 based on the condition specified in cell F2. The output is an array and is returned to cell F4 and cells below as far as needed.
4. Filter values based on a condition
The Filter function filters values in cell range C3:C7 if a value in B3:B7 on the corresponding row equals "France" (Cell F2).
Formula in cell D3:
There is a formula for you that have an earlier Excel version than Excel 365: VLOOKUP - Return multiple values [vertically]
The FILTER function has three arguments, the second one is an array that evaluates to TRUE or FALSE or their numerical equivalents 1 or 0 (zero).
FILTER(array, include, [if_empty])
B3:B7=F2
The equal sign is a logical operator that evaluates if cell values in B3:B7 are equal to cell value in F2, one by one.
B3:B7=F2
becomes
{"Germany";"Italy";"France";"Italy";"France"}="France"
becomes
{"Germany"="France";"Italy"="France";"France"="France";"Italy"="France";"France"="France"}
and returns {FALSE; FALSE; TRUE; FALSE; TRUE}.
The image above shows the array in column A, the values correspond to the values in column B, True is on the same row as France row 5 and 7. False is on all remaining rows.
The FILTER function uses this array containing boolean values (TRUE or False) to determine which values to return from column C. "Apple" and "Lemon" are on the same row as France row 5 and 7. The values are returned to cell F4 and cells below if needed.
The FILTER function may return an array and Microsoft calls this a dynamic array meaning the values are automatically entered to cells below without the need for an array formula.
1.1 Why does the FILTER function return a #NAME? error?
First, make sure you correctly spelled the FILTER function. If the FILTER function still returns a #NAME? error you probably use an earlier Excel version and can't the FILTER function unless you upgrade to Excel 365.
There is a small formula you can use if you don't have access to the FILTER function, check it out here: VLOOKUP - Return multiple values [vertically]
1.2 Is the FILTER function available for Excel versions 2003, 2007, 2010, 2013, 2016, and 2019?
No, only Excel 365 subscribers have it. However, I made a small formula that works fine, check it out here: VLOOKUP - Return multiple values [vertically]
1.3 The FILTER function returns a #SPILL! error, why?
The FILTER function returns an array of values and tries to automatically use the appropriate cell range needed to show all values. If one or more cells are occupied with other values the FILTER function returns #SPILL! error.
You have two options, delete or move the values that cause the error or deploy the FILTER function in another cell that has empty cells below.
1.4 Why does the FILTER function return a #CALC! error?
The FILTER function returns a #CALC! error if the output result has no values, make sure you enter the third argument to define a value if dynamic array is empty, to avoid the #CALC! error.
1.5 Can I use the FILTER function with an Excel Table and structured references?
Yes, you can. The FILTER function recalculates the output automatically if you add, edit or delete values in the Excel Table.
1.6 Can the FILTER function handle error values?
No, the FILTER function stops working if there are error values in the second argument. An error in the first argument is passed on to the output array with other regular values.
1.7 Is the FILTER function case sensitive?
No, the FILTER function is not case sensitive if you use the equal sign. Read the next section for how to make the FILTER function case sensitive.
5. Filter values based on a condition - case sensitive
The image above shows a formula in cell F4 that extracts values from column C if the corresponding values in column B match the value in cell F2.
There is a formula for you that have an earlier Excel version than Excel 365: Case sensitive lookup and return multiple values
The EXACT function returns True if both arguments are exactly the same considering upper and lower letters as well.
EXACT(text1, text2)
The EXACT function allows you to use a cell range in the first argument and the result is an array that matches the size of the first argument as long as the second argument is a single value.
EXACT(B3:B7,F2)
becomes
EXACT({"france"; "Italy"; "France"; "Italy"; "france"}, "france")
and returns {TRUE; FALSE; FALSE; FALSE; TRUE}.
FILTER(C3:C7,EXACT(B3:B7,F2))
becomes
FILTER(C3:C7,{TRUE; FALSE; FALSE; FALSE; TRUE})
becomes
FILTER({"Pear"; "Orange"; "Apple"; "Banana"; "Lemon"}, {TRUE; FALSE; FALSE; FALSE; TRUE})
and returns {"Pear"; "Lemon"} in cell range F4:F5.
6. Filter values if not equal to
The image above demonstrates the FILTER function in cell F4, it returns all values from column C if the corresponding values in column B are not equal to the value in cell F2.
The less than and larger than characters combined means "not equal to".
B3:B7<>F2
becomes
{"Germany"; "Italy"; "France"; "Italy"; "France"}<>"France"
and returns {TRUE; TRUE; FALSE; TRUE; FALSE}.
FILTER(C3:C7,B3:B7<>F2)
becomes
FILTER({"Pear";"Orange";"Apple";"Banana";"Lemon"}, {TRUE; TRUE; FALSE; TRUE; FALSE})
and returns {"Pear"; "Orange"; "Banana"} in cell range F4:F6.
7. Filter values smaller than a condition
The image above shows a formula in cell F4 that extracts values from column B if the corresponding value in column C is less than the number in cell F2.
The less than character < is a logical operator that checks if a number is smaller than another number. In this demonstration, we will apply this to a cell range C3:C7. The logical expression is:
C3:C7<F2
becomes
{6;2;7;3;2}<5
and returns {FALSE; TRUE; FALSE; TRUE; TRUE}.
FILTER(B3:B7, C3:C7<F2)
becomes
FILTER({"Pear"; "Orange"; "Apple"; "Banana"; "Lemon"}, {FALSE; TRUE; FALSE; TRUE; TRUE})
and returns {"Orange"; "Banana"; "Lemon"}.
8. Filter values if larger than the given condition
Formula in cell F4:
The larger than character > is a logical operator that evaluates to True if a number is larger than another number otherwise False. In this demonstration, we will apply this to a cell range C3:C7. The logical expression is:
C3:C7>F2
becomes
{6;2;7;3;2}>5
and returns {TRUE; FALSE; TRUE; FALSE; FALSE}.
FILTER(B3:B7, C3:C7>F2)
becomes
FILTER({"Pear";"Orange";"Apple";"Banana";"Lemon"}, {TRUE; FALSE; TRUE; FALSE; FALSE})
and returns {"Pear"; "Apple"}.
9. Filter values if cell contains given string
The image above shows a formula in cell F4 that extracts values from column C if the corresponding value in column B contains the given string in cell F2.
Formula in cell F4:
The formula in cell F4 returns "Pear", "Apple" and "Lemon" because the corresponding values in column B "Germany", "France" and "France" contain string "r".
Step 1 - Identify cells containing string
The SEARCH function has these arguments: SEARCH(find_text,within_text, [start_num])
It returns a number representing the character position of the found string, an error is returned if not found. The SEARCH function does not perform a case sensitive search, use the FIND function for that.
SEARCH(F2,B3:B7))
becomes
SEARCH("r",{"Germany"; "Italy"; "France"; "Italy"; "France"}))
and returns {3; #VALUE!; 2; #VALUE!; 2}.
Step 2 - Replace errors
The FILTER function can't handle errors in the second argument include. FILTER(array, include, [if_empty])
ISNUMBER(SEARCH(F2,B3:B7))
becomes
ISNUMBER({3; #VALUE!; 2; #VALUE!; 2})
and returns {TRUE; FALSE; TRUE; FALSE; TRUE}.
Step 3 - Filter array
FILTER(C3:C7,ISNUMBER(SEARCH(F2,B3:B7)))
becomes
FILTER(C3:C7, {TRUE; FALSE; TRUE; FALSE; TRUE})
becomes
FILTER({"Pear"; "Orange"; "Apple"; "Banana"; "Lemon"}, {TRUE; FALSE; TRUE; FALSE; TRUE})
and returns {"Pear"; "Apple"; "Lemon"}.
10. Filter values if cell doesn't contain the given string
The image above shows a formula in cell F4 that extracts values from column C if the corresponding value in column B does not contain the given string in cell F2.
Formula in cell F4:
The formula in cell F4 returns "Orange" and "Banana" because the corresponding values in column B "Italy" and "Italy" do not contain string "r".
Step 1 - Identify cells that contain the string
The SEARCH function has these arguments: SEARCH(find_text,within_text, [start_num])
It returns a number representing the character position of the found string, an error is returned if not found. The SEARCH function does not perform a case sensitive search, use the FIND function for that.
SEARCH(F2,B3:B7))
becomes
SEARCH("r",{"Germany"; "Italy"; "France"; "Italy"; "France"}))
and returns {3; #VALUE!; 2; #VALUE!; 2}.
Step 2 - Identify errors
The FILTER function can't handle errors in the second argument include. FILTER(array, include, [if_empty])
ISERROR(SEARCH(F2,B3:B7))
becomes
ISNUMBER({3; #VALUE!; 2; #VALUE!; 2})
and returns {FALSE; TRUE; FALSE; TRUE; FALSE}.
Step 3 - Filter array
FILTER(C3:C7, ISERROR(SEARCH(F2,B3:B7)))
becomes
FILTER(C3:C7, {FALSE; TRUE; FALSE; TRUE; FALSE})
becomes
FILTER({"Pear"; "Orange"; "Apple"; "Banana"; "Lemon"}, {FALSE; TRUE; FALSE; TRUE; FALSE})
and returns {"Orange"; "Banana"} in cell range F4:F5.
11. Filter values that begin with
The formula above in cell F4 extracts values from column C if the corresponding value in column B begins with the given string in cell F2.
Formula in cell F4:
The formula in cell F4 returns all rows from cell range B3:C7 that begins with the string specified in cell F2.
Step 1 - Calculate character length of value in cell F2
The LEN function counts the characters in a cell or string.
LEN(F2)
becomes
LEN("00")
and returns 2.
Step 2 - Extract characters
The LEFT function returns a specific number of characters from a cell value or string starting from the left. LEFT(text,[num_chars])
LEFT(B3:B7,LEN(F2))
becomes
LEFT(B3:B7,2)
becomes
LEFT({"001"; "024"; "008"; "018"; "004"}, 2)
and returns {"00";"02";"00";"01";"00"}.
Step 3 - Compare with value in cell F2
The equal sign lets you compare values (not case sensitive), it returns a boolean value True or False.
LEFT(B3:B7,LEN(F2))=F2
becomes
{"00";"02";"00";"01";"00"}="00"
and returns
{TRUE; FALSE; TRUE; FALSE; TRUE}.
Step 4 - Filter values
FILTER(B3:C7,LEFT(B3:B7,LEN(F2))=F2)
becomes
FILTER(B3:C7,{TRUE; FALSE; TRUE; FALSE; TRUE})
becomes
FILTER({"001", "Pear"; "024", "Orange"; "008", "Apple"; "018", "Banana"; "004", "Lemon"},{TRUE; FALSE; TRUE; FALSE; TRUE})
and returns
{"001","Pear";"008","Apple";"004","Lemon"} in cell range F4:G7.
12. Filter values that end with a specific string
The formula above in cell F4 extracts values from column C if the corresponding value in column B ends with the given string in cell F2.
Formula in cell F4:
The formula in cell F4 returns all rows from cell range B3:C7 that end with 8 in column B.
Step 1 - Calculate character length of the value in cell F2
The LEN function counts the characters in a cell or string.
LEN(F2)
becomes
LEN("8")
and returns 1.
Step 2 - Extract characters
The RIGHT function returns a specific number of characters from a cell value or string starting from the left. LEFT(text,[num_chars])
LEFT(B3:B7,LEN(F2))
becomes
LEFT(B3:B7,1)
becomes
LEFT({"001"; "024"; "008"; "018"; "004"}, 1)
and returns {"1";"4";"8";"8";"4"}.
Step 3 - Compare with value in cell F2
The equal sign lets you compare values (not case sensitive), it returns a boolean value True or False.
RIGHT(B3:B7,LEN(F2))=F2
becomes
{"1";"4";"8";"8";"4"}="8"
and returns
{FALSE; FALSE; TRUE; TRUE; FALSE}.
Step 4 - Filter values
FILTER(B3:C7,LEFT(B3:B7,LEN(F2))=F2)
becomes
FILTER(B3:C7, {FALSE; FALSE; TRUE; TRUE; FALSE})
becomes
FILTER({"001", "Pear"; "024", "Orange"; "008", "Apple"; "018", "Banana"; "004", "Lemon"}, {FALSE; FALSE; TRUE; TRUE; FALSE})
and returns
{"008", "Apple"; "018", "Banana"} in cell range F4:G5.
13. Filter values based on a condition sorted A to Z
Formula in cell F4:
The formula in cell F4 extracts values from column B based on a condition specified in cell F2, If the condition matches a value in column C the corresponding value from column B is returned. The array is sorted from A to Z.
Step 1 - Logical expression
The equal sign allows you to compare the value in cell F2 to values in cell range B3:B9. The result is an array containing boolean values True or False.
B3:B9=F2
becomes
{"Germany"; "Italy"; "France"; "Italy"; "France"; "Germany"; "France"}="France"
and returns
{FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; TRUE}
Step 2 - Filter values
The array containing boolean values determine which values in cell range C3:C9 to filter.
FILTER(C3:C9,B3:B9=F2)
becomes
FILTER(C3:C9,{FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; TRUE})
becomes
FILTER({"Pear"; "Orange"; "Grape"; "Banana"; "Apple"; "Strawberry"; "Lemon"}, {FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; TRUE})
and returns
{"Grape"; "Apple"; "Lemon"}.
Step 3 - Sort values
The SORT function is available for Excel 365 users and has the following arguments: SORT(array,[sort_index],[sort_order],[by_col])
It lets you sort an array from A to Z if you leave the remaining arguments, they are optional anyway.
SORT(FILTER(C3:C9,B3:B9=F2))
becomes
SORT({"Grape"; "Apple"; "Lemon"})
and returns
{"Apple"; "Grape"; "Lemon"}
in cell range F4:F6.
Note, the following formula sorts from Z to A:
=SORT(FILTER(C3:C9, B3:B9=F2),,-1)
14. Filter values based on criteria applied to a column
The formula in cell E7 filters the values in cell range B3:C7 based on two values specified in cell range F2:F3.
If any of the two values match a value in column B the corresponding value from column C is returned as well as the matching value.
Formula in cell E7:
The COUNTIF function counts values based on a condition or criteria, here is how it is done. COUNTIF(range, criteria)
COUNTIF(F2:F3, B3:B7)
becomes
COUNTIF({"France"; "Italy"}, {"Germany"; "Italy"; "France"; "Italy"; "France"})
and returns
{0; 1; 1; 1; 1}. 0 (zero) is the equivalent to False and every other value positive or negative evaluates to True.
FILTER(B3:C7, {0; 1; 1; 1; 1})
becomes
FILTER({"Germany", "Pear"; "Italy", "Orange"; "France", "Apple"; "Italy", "Banana"; "France", "Lemon"}, {0; 1; 1; 1; 1})
and returns
{"Italy", "Orange"; "France", "Apple"; "Italy", "Banana"; "France", "Lemon"}.
15. Filter values based on one condition per column - AND logic
The formula in cell F10 extracts rows from cell range B3:D7 if two conditions are met, specified in cell F4 and G4. The first condition is compared to column B and the second condition is compared to column C.
A row is extracted if both conditions are met on the same row.
Formula in cell F7:
The first logical expression is B3:B7=F4.
B3:B7=F4
becomes
{"Germany";"Italy";"France";"Italy";"France"}="Italy"
and returns
{FALSE; TRUE; FALSE; TRUE; FALSE}
The second logical expression is {2; 5; 4; 6; 3}=5.
{2; 5; 4; 6; 3}=5
returns
{FALSE; TRUE; FALSE; FALSE; FALSE}
To apply AND logic we must multiply the arrays using the asterisk character. The parentheses allow us to control the calculations, we want to calculate the expressions inside the parentheses before we multiple the arrays.
(B3:B7=F4)*(C3:C7=G4)
becomes
({FALSE; TRUE; FALSE; TRUE; FALSE})*({FALSE; TRUE; FALSE; FALSE; FALSE})
and returns
{0; 1; 0; 0; 0}.
Boolean values are automatically converted to their numerical equivalents when we calculate arithmetic operations.
True * True equals 1
True * False equals 0 (zero)
False * True equals 0 (zero)
False * False equals 0 (zero)
FILTER(B3:D7, (B3:B7=F4)*(C3:C7=G4))
becomes
FILTER(B3:D7, {0; 1; 0; 0; 0})
becomes
FILTER({"Germany", 2, "Pear"; "Italy", 5, "Orange"; "France", 4, "Apple"; "Italy", 6, "Banana"; "France", 5, "Lemon"}, {0; 1; 0; 0; 0})
and returns {"Italy", 5, "Orange"}.
16. Filter values based on one condition per column - OR logic
The formula in cell F10 extracts rows from cell range B3:D7 if any of the two conditions are met, specified in cell F4 and G4. The first condition is compared to column B and the second condition is compared to column C.
A row is extracted if any of the conditions are met on the same row.
Formula in cell F7:
The first logical expression is B3:B7=F4.
B3:B7=F4
becomes
{"Germany";"Italy";"France";"Italy";"France"}="Italy"
and returns
{FALSE; TRUE; FALSE; TRUE; FALSE}
The second logical expression is {2; 5; 4; 6; 3}=5.
{2; 5; 4; 6; 5}=5
returns
{FALSE; TRUE; FALSE; FALSE; TRUE}
(B3:B7=F4)+(C3:C7=G4)
becomes
({FALSE; TRUE; FALSE; TRUE; FALSE}) + ({FALSE; TRUE; FALSE; FALSE; TRUE})
and returns
{0; 2; 0; 1; 1}
True + True equals 2 (True)
True + False equals 1 (True)
False + True equals 1 (True)
False + False equals 0 (False)
FILTER(B3:D7, (B3:B7=F4)+(C3:C7=G4))
becomes
FILTER({"Germany", 2, "Pear"; "Italy", 5, "Orange"; "France", 4, "Apple"; "Italy", 6, "Banana"; "France", 5, "Lemon"}, {0; 2; 0; 1; 1})
and returns
{"Italy", 5, "Orange"; "Italy", 6, "Banana"; "France", 5, "Lemon"}.
17. #CALC! error returns [if_empty] argument
The FILTER function in cell F4 returns a #CALC! error. The value in cell F2 is not found in any of the cells in B3:B7.
The FILTER function returns #CALC! error instead of an empty array. The third argument allows you to customize what to return if the FILTER function returns nothing, see below.
'FILTER' function examples
The following 66 articles contain the FILTER function.
First, let me explain the difference between unique values and unique distinct values, it is important you know the difference […]
This post explains how to lookup a value and return multiple values. No array formula required.
This article describes how to build a calendar showing all days in a chosen month with corresponding scheduled events. What's […]
This article demonstrates formulas that extract values that exist only in one column out of two columns. There are text […]
This article demonstrates formulas that extract differences between two given lists. The first formula in cell B11 extracts values from […]
This article demonstrates how to construct a formula that counts unique distinct values based on a condition. The image above […]
The following image shows you a data set in columns B and C. The formula in cell E2 extracts a […]
The array formula in cell C2 extracts duplicate values from column A. Only one duplicate of each value is displayed […]
This webpage demonstrates formulas that merge three non-adjacent cell ranges. What's on this webpage Extract a list of duplicates from […]
Cell range B2:E11 contains values, the formula in cell B15 extracts unique distinct values in B2:E11, ignores blanks, and returns […]
This article demonstrates formulas that extract unique distinct values and ignore blank empty cells. Table of contents Extract a unique […]
This article demonstrates ways to extract unique distinct sorted from A to Z ignoring blanks, and based on a condition. […]
Lookup with criteria and return records.
The array formula in cell B3 extracts overlapping dates based on the date ranges in columns D and E. What's […]
This article demonstrates formulas that extract duplicate values from a column, however, column D contains values that you don't want […]
This article describes two formulas that extract duplicates from a multi-column cell range, the first one is built for Excel […]
I this article I will show you how to get numerical values from a cell range manually and using an […]
This article presents methods for filtering rows in a dataset based on a start and end date. The image above […]
This article demonstrates ways to extract shared values in different cell ranges, two and three cell ranges. The Excel 365 […]
This article demonstrates formulas that extract sorted unique distinct values from a cell range containing also blanks. Unique distinct values […]
This article demonstrates two formulas that extract distinct values from a filtered Excel Table, one formula for Excel 365 subscribers […]
Filtering unique distinct text values and sorting them based on the sum of adjacent values can easily be done by […]
The image above shows an array formula in cell B12 that extracts values shared by cell range B2:D4 (One) and […]
This article demonstrates formulas and Excel tools that extract duplicates based on three conditions. The first and second condition is […]
This blog article describes how to extract coinciding date ranges using array formulas, the image above shows random date ranges […]
Table of contents Filter unique distinct row records Filter unique distinct row records but not blanks Filter unique distinct row […]
Table of Contents Filter unique distinct values based on a date range Filter unique distinct values based on a date […]
The formula in cell B8, shown above, extracts dates not included in the specified date ranges, in other words, dates […]
Table of Contents How to find the largest duplicate number How to find the largest duplicate number - Excel 365 […]
This article demonstrates how to return the latest date based on a condition using formulas or a Pivot Table. The […]
This article demonstrates ways to extract names and corresponding populated date ranges from a schedule using Excel 365 and earlier […]
This article demonstrates a formula that extracts unique values from a column also considering upper and lower characters (case sensitive). […]
Question: How to extract email addresses from this sheet? Answer: It depends on how the emails are populated in your worksheet? […]
This article describes a formula that returns all rows containing at least one digit 0 (zero) to 9. What's on […]
This article shows how to create a formula that sorts numbers from small to large excluding zeros. I will also […]
This article demonstrates a formula that points out row numbers of records that overlap the current record based on a […]
This article demonstrates several ways to check if a cell contains any value based on a list. The first example […]
This article demonstrates how to use INDEX and MATCH functions to match multiple conditions and return multiple results. The Excel […]
This article demonstrates formulas that let you perform lookups using two or more conditions. The image above shows two conditions […]
This article demonstrates a formula that extracts unique distinct records/rows for a given month specified in cell C2, see the […]
This article demonstrates how to calculate dates in a given date range (cells B13 and B14) that don't overlap the […]
This article demonstrates a formula that extracts values based on a condition and sorts the returned values based on values […]
This article demonstrates how to find a value in a column and concatenate corresponding values on the same row. The […]
This article demonstrates a formula that extracts values from a column based on a date range criteria and another condition. […]
This article explains how to perform multiple lookups based on values in one cell with a delimiting character using a […]
Excel 2010 has a PowerPivot feature and DAX formulas that let you work with multiple tables of data. You can […]
This article demonstrates how to extract records/rows based on two conditions applied to two different columns, you can easily extend […]
This article demonstrates two formulas, they both accomplish the same thing. The Excel 365 formula is much smaller and is […]
This article demonstrates array formulas that search for cell values containing a search string and returns corresponding values on the […]
This article demonstrates formulas that let you perform partial matches based on multiple strings and return those strings if all […]
This article demonstrates a formula that extracts a row or record from a data table using two strings as criteria. […]
This article demonstrates two different formulas, one for Excel 365 and one for earlier versions. Table of Contents Reverse a […]
This article demonstrates array formulas that perform a wildcard search based on a sequence of values. The formulas return the […]
This article demonstrates array formulas that identify two search values in a row or in a sequence. The image above […]
This article explains different techniques that filter rows/records that contain a given text string in any of the cell values […]
Table of Contents Search values distributed horizontally and return the corresponding value Filter values distributed horizontally - Excel 365 1. […]
This article demonstrates how to extract multiple numbers based on a condition and return a sorted list from small to […]
This article demonstrates two ways to calculate expenses evenly split across multiple people. The first one is a formula solution, […]
This article demonstrates how to extract unique distinct values based on a condition and also sorted from A to z. […]
This article demonstrates how to extract multiple values based on a search value and display them sorted from A to […]
This article shows how to extract unique distinct values based on a condition applied to an adjacent column using formulas. […]
VLOOKUP and return multiple matches based on many criteria.
Table of Contents Vlookup with multiple matches returns a different value Lookup with multiple matches returns different values - Excel […]
Question: Does anyone know how to do a VLOOKUP of three columns to pull a single record? Table of Contents VLOOKUP […]
This article shows how to compare two nonadjacent cell ranges and extract values that exist only in one of the […]
This article demonstrates three different ways to filter a data set if a value contains a specific string and if […]
Functions in this article
Functions in 'Lookup and reference' category
The FILTER function function is one of many functions in the 'Lookup and reference' category.
Excel function categories
Excel categories
2 Responses to “How to use the FILTER function”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
How to combine trick 6 with trick 11, i.e.
https://i.postimg.cc/W1zRH7MM/Filter-function-criteria-edit.png
Piotr,
Great question!
Here is how to filter values that contain any of the given strings:
Formula in cell E6:
=FILTER(B3:C7, MMULT(ISNUMBER(SEARCH(TRANSPOSE(F2:F3), B3:B7))*1, ROW(F2:F3)^0))