How to use the SEARCH function
What is the SEARCH function?
The SEARCH function returns a number representing the position of character at which a specific text string is found reading left to right. It is not a case-sensitive search.
Table of Contents
1. SEARCH function syntax
SEARCH(find_text,within_text, [start_num])
2. SEARCH function arguments
find_text | Required. Is the text you want to find. Wildcard characters (? and *) are allowed. |
within_text | Required. Is the text in which you want to search for find_text. |
[start_num] | Optional. Is the character number in within_text, counting from the left at which you want to start searching. If omitted 1 is used. |
3. SEARCH function example
The image above demonstrates the function in cell D3.
The first argument find_text is a cell reference to the value in cell C3, the function will look for the value specified in cell C3 in the value in cell B3.
It returns number 11 in this example. Text string "blue" is found in position 11 if you count characters from left to right "My car is blue".
Row 7Â shows the text string with a single character in each cell, row 8 shows the count for each cell.
The SEARCH function is not case sensitive, use the FIND function if lower and upper case letters are important.
The image above shows that using a text string in uppercase letters (cell C3) still matches the text in cell B3.
Formula in cell C3:
If the text string is not found the SEARCH function returns a #VALUE! error. The image above shows the erro output from the SEARCH function in cell C3.
Text string "red" is not found in cell B3 "brown horse", the issue with error values is that they break a formula, however, there are workarounds.
Use the ISNUMBER function to avoid breaking the formula. It returns TRUE if the returned value is a number and FALSE for everything else even errors.
Formula in cell C5:
ISNUMBER(SEARCH("red", B5))
becomes
ISNUMBER(SEARCH("red", "blue whale"))
becomes
ISNUMBER(#VALUE!)
and returns FALSE in cell C5.
4. SEARCH function not working
The SEARCH function returns a #VALUE! error if the string is not found.
5. SEARCH function - wildcard characters
There are two wildcard characters you can use in the SEARCH function.
Character | Wildcard | Description |
* | asterisk | Matches 0 (zero) to any number of characters. |
? | question mark | Matches one character only. |
Formula in cell D3:
The SEARCH function in cell D3 returns 1, cell C3 contains *blue. The asterisk matches any number of characters even 0 (zero).
*blue matches the entire text string in cell B3 "My car is blue" and therefore matches the first character and returns 1.
Formula in cell D4:
Cell C4 contains blue* and matches at the eleventh character, the asterisk matches any number of characters from zero and up.
Formula in cell D5:
The question mark character matches any single character, ?blue matches "My car is blue" at the tenth character. The ? matches the blank (space) as well and the SEARCH function returns 10.
Formula in cell D6:
blue? doesn't match text "My car is blue" and returns #VALUE! error. The question mark matches any single character but string "My car is blue" has no character after blue.
6. Count how many times a specific string is found in a cell using the SEARCH function?
You can't use the SEARCH function to count how many time a specific string exists in a cell, it will only return the number of the character of the string that first matches, reading from left to right.
This article explains how to Count specific text string in a cell.
7. Can you count how many times a specific string is found in a cell range using the SEARCH function?
Yes, but only one instance per cell. Formula in cell D3:
If you are an Excel 365 subscriber you can use the regular formula above. Excel users with previous versions can use the formula below.
Let me explain how these two formula work.
SEARCH(C3,B3:B5)
becomes
SEARCH("aa", {"aa bb cc aa dd"; "bb cc dd"; "aa bb cc aa dd"})
and returns {1; #VALUE!; 1}. The numbers indicate that a matching string is found.
ISNUMBER(SEARCH(C3,B3:B5))
becomes
ISNUMBER({1; #VALUE!; 1})
and returns {TRUE; FALSE; TRUE}. The SUM and SUMPRODUCT functions can't sum add boolean values, to convert boolean values to numbers simply multiply with 1.
ISNUMBER(SEARCH(C3,B3:B5))*1
becomes
{TRUE; FALSE; TRUE}*1
and returns {1;0;1}. 1 is the equivalent of boolean value TRUE and 0 (zero) is boolean value FALSE.
8. SEARCH function with multiple search values?
You can use multiple text strings, however, if there are more than one instance of a specific string only one is counted.
For example cell B3 contains two "aa" but the formula in cell D3 counts only one instance.
The formula returns 2 because text strings "aa" and "bb" are found in cell B3. The formula is exactly the same as the one above so I won't explain it again, however, note that the cell references are different.
9. How to get the position of the second instance?
The string "aa" we are looking for exists twice in cell B3, the following formula returns a number representing the position of the character of the string the second time it occurs.
This formula changes the first instance to another string so that the SEARCH function then finds the position of the second instance of the string we are looking for.
SEARCH(C3,B3) finds the position of the first instance, it returns 1. The REPLACE function then changes the first string to something else, in this case, character "|". If your cell contains this character already then I recommend changing it to something that is not used in the cell so the formula doesn't get confused.
REPLACE(B3,SEARCH(C3,B3),LEN(C3),REPT("|", LEN(C3)))
becomes
REPLACE(B3,SEARCH(C3,B3),LEN(C3),REPT("|", LEN("aa")))
becomes
REPLACE(B3,SEARCH(C3,B3),LEN(C3),REPT("|", 2))
becomes
REPLACE(B3,SEARCH(C3,B3),LEN(C3),"||")
becomes
REPLACE(B3,SEARCH(C3,B3),2,"||")
becomes
REPLACE(B3,1,2,"||")
becomes
REPLACE("aa bb cc aa dd",1,2,"||")
and returns "|| bb cc aa dd".
SEARCH(C3,REPLACE(B3,SEARCH(C3,B3),LEN(C3),REPT("|", LEN(C3))))
becomes
SEARCH(C3,"|| bb cc aa dd")
and returns 10 in cell D3.
10. How to get the relative position of all instances?
The following formula works only in Excel 365, it returns numbers representing the position of the found instances in a cell.
Dynamic array formula in cell C3:
7.1 Explaining formula in cell C3
Step 1 - Calculate the number of characters in a given cell
LEN(B3)
Step 2 - Create a sequence from 1 to n
SEQUENCE(LEN(B3))
Step 3 - Create an array of substrings
MID(B3, SEQUENCE(LEN(B3)), LEN(E3))
Step 4 - Compare substrings to condition
MID(B3, SEQUENCE(LEN(B3)), LEN(E3))=E3
Step 5 - Filter corresponding numbers
FILTER(SEQUENCE(LEN(B3)), MID(B3, SEQUENCE(LEN(B3)), LEN(E3))=E3)
Step 6 - Concatenate strings
TEXTJOIN(", ", TRUE, FILTER(SEQUENCE(LEN(B3)), MID(B3, SEQUENCE(LEN(B3)), LEN(E3))=E3))
'SEARCH' function examples
This post explains how to lookup a value and return multiple values. No array formula required.
The array formula in cell F3 counts cells in column B that contains at least one of the values in […]
The formula in cell C3 grabs the first word in B3 using a blank as the delimiting character. =LEFT(B3,SEARCH(" ",B3)-1) […]
Functions in 'Text' category
The SEARCH function function is one of many functions in the 'Text' category.
Excel function categories
Excel categories
3 Responses to “How to use the SEARCH 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.
Just an additon..
"The function works the same as the search function except case-sensitive" & Find doesn't works with wildcard characters — the question mark (?) and asterisk (*) where SEARCH can.. :)
Regards,
Deb
Thank you, Deb!
[…] SEARCH(find_text,within_text, [start_num]) Returns the number of the character at which a specific character or text string is first found, reading left to right (not case sensitive) […]