How to use the SUBSTITUTE function
Formula in cell E3:
The SUBSTITUTE function replaces a specific text string in a value. It is case sensitive meaning it differentiates between upper and lower letters.
The image above shows the SUBSTITUTE function cell E3 substituting the word "red" with "brown" based on value in cell B3.
Table of Contents
1. Introduction
What other text manipulation functions are available in Excel?
- REPLACE function: The REPLACE function is a string function that replaces a specified part of a text string with another text string. It takes three arguments: the original text string, the text to be replaced, and the replacement text. The function returns the modified text string with the specified part replaced.
- TEXTBEFORE function: The TEXTBEFORE function is a string function that returns a specified number of characters from the beginning of a text string, before a specified delimiter. It takes two arguments: the original text string and the delimiter. The function returns the text before the delimiter.
- TEXTAFTER function: The TEXTAFTER function is a string function that returns a specified number of characters from the end of a text string, after a specified delimiter. It takes two arguments: the original text string and the delimiter. The function returns the text after the delimiter.
There are a lot more text functions in Excel, however, these are the most similar functions compared to the SUBSTITUTE function.
2. Syntax
SUBSTITUTE(text, old_text, new_text, [instance_num])
text | Required. The value you want to substitute text in. |
old_text | Required. The text string you are looking for in the value. |
new_text | Required. The text you want to substitute. |
[instance_num] | Optional. Which instance to replace. If not entered every instance is substituted. |
3. Example
The SUBSTITUTE function, in the above example, substitutes the word "brown" with "red" at the second found instance. Cell B6 contains "brown", cell C6 contains "red" and cell D6 contains 2 representing which instance to replace.
Formula in cell B9:
4. Wildcard
You can't use wildcard characters in the SUBSTITUTE function, however, you can use the built-in feature "Find and Replace" to do the same thing.
You can use the following characters:
- ? (question mark) - a single character
- * (asterisk) - any number of characters zero included
Here are the steps to use the "Find and Replace" dialog box:
- Select a cell range you want to use.
- Press CTRL + H to open the "Find and Replace" dialog box.
- Type the search string in " Find what:".
- Type the substitution string in "Replace with:".
- Press with the left mouse button on the "Replace" button to replace strings in a single cell.
Press with the left mouse button on the "Replace All" button to replace strings in all cells on the active worksheet.
5. How to substitute quotation marks
The image above demonstrates how to remove quotation marks using the SUBSTITUTE function.
Formula in cell B6:
6. How to substitute multiple strings
You can nest the SUBSTITUTE function to substitute multiple values in one calculation, however, the formula grows quickly if you have many strings to substitute.
Formula in cell B6:
Explaining formula
Step 1 - Substitute first string
SUBSTITUTE(B3, D6, E6)
becomes
SUBSTITUTE("A red fox", "red", "grey")
and returns "A grey fox".
Step 2 - Substitute second string
SUBSTITUTE(SUBSTITUTE(B3, D6, E6), D7, E7)
becomes
SUBSTITUTE("A grey fox", D7, E7)
becomes
SUBSTITUTE("A grey fox", "fox", "wolf")
and returns "A grey wolf".
Recommended reading
Substitute multiple text strings [UDF]
7. Substitute from right
Formula in cell B6:
Explaining formula
Step 1 - Substitute string with nothing
SUBSTITUTE(B3, D6, "")
becomes
SUBSTITUTE("555-12 34 12 56 12 78 12 90",12,"")
and returns
"555- 34 56 78 90".
Step 2 - Count characters
The LEN function counts the number of characters.
LEN(value)
LEN(SUBSTITUTE(B3, D6, ""))
becomes
LEN("555- 34 56 78 90")
and returns 19. "555- 34 56 78 90" contains 19 characters.
Step 3 - Count characters in cell B3
LEN(B3)
becomes
LEN("555-12 34 12 56 12 78 12 90")
and returns 27.
Step 4 - Subtract character counts
LEN(B3)-LEN(SUBSTITUTE(B3, D6, ""))
becomes
27 - 19 equals 8.
Step 5 - Divide with old text character count
The division character lets you divide numbers in an Excel formula. The parentheses allow you to control the order of calculation.
(LEN(B3)-LEN(SUBSTITUTE(B3, D6, "")))/LEN(D6)
becomes
(27 - 18)/LEN(12)
becomes
(27 - 18)/2
becomes
8/2 equals 4. There are four instances of value 12 in cell B3. "555-12 34 12 56 12 78 12 90"
Step 6 - Substitute value based on instance
SUBSTITUTE(B3, D6, D9, (LEN(B3)-LEN(SUBSTITUTE(B3, D6, "")))/LEN(D6))
becomes
SUBSTITUTE("555-12 34 12 56 12 78 12 90", 12, "AA", 4)
and returns "555-12 34 12 56 12 78 AA 90".
8. Substitute all letters with a given string
This formula substitutes all letters, upper and lower letters, to a given string.
Array formula in cell B6:
The last part of the formula contains the string you want to use, bolded in the formula below.
TEXTJOIN(, TRUE, IF(ISERROR(SEARCH(MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ")), MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "|"))
8.1 How to enter an array formula
Excel 365 users may enter the formula as a regular formula, no need to follow the steps below.
- Copy above formula
- Double press with the left mouse button on cell B3, a prompt appears.
- Paste the formula.
- Press and hold CTRL + SHIFT simultaneously.
- Press Enter once.
- Release all keys.
The formula bar contains a leading and trailing curly bracket if you followed the above steps, it indicates that the formula is an array formula. Don't enter these characters yourself.
8.2 Explaining formula
Step 1 - Count characters
The LEN function counts the number of characters.
LEN(value)
LEN(B3)
becomes
LEN("ABC-12 VF 12 56 12 aC 12 90")
and returns 27.
Step 2 - Create a cell ref
The INDEX function lets you build a dynamic cell reference.
INDEX(A:A, LEN(B3))
becomes
INDEX(A:A, 27)
and returns A27.
Step 3 - Create a cell ref to a cell range
The colon character lets you append a cell ref to a cell ref.
A1:INDEX(A:A, LEN(B3))
returns A1:A27.
Step 4 - Create row numbers
The ROW function calculates the row number of a cell reference.
ROW(ref)
ROW(A1:INDEX(A:A, LEN(B3)))
becomes
ROW(A1:A27)
and returns {1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27}.
Step 5 - Create an array containing each character in cell B3
The MID function returns a substring from a string based on the starting position and the number of characters you want to extract.
MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1)
becomes
MID("ABC-12 VF 12 56 12 aC 12 90", {1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27}, 1)
and returns
{"A"; "B"; "C"; "-"; "1"; "2"; " "; "V"; "F"; " "; "1"; "2"; " "; "5"; "6"; " "; "1"; "2"; " "; "a"; "C"; " "; "1"; "2"; " "; "9"; "0"}.
Step 6 - Calculate position of each character in the alphabet
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.
SEARCH(find_text,within_text, [start_num])
SEARCH(MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ")
becomes
SEARCH({"A"; "B"; "C"; "-"; "1"; "2"; " "; "V"; "F"; " "; "1"; "2"; " "; "5"; "6"; " "; "1"; "2"; " "; "a"; "C"; " "; "1"; "2"; " "; "9"; "0"}, "ABCDEFGHIJKLMNOPQRSTUVWXYZ")
and returns
{1; 2; 3; #VALUE!; #VALUE!; #VALUE!; #VALUE!; 22; 6; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; 1; 3; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!}
Note that the SEARCH function returns an error value if the character is not found in the alhpabet.
Step 7 - Find error values in the array
The ISERROR function returns TRUE if a value is an error value.
ISERROR(value)
ISERROR(SEARCH(MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ"))
becomes
ISERROR({1; 2; 3; #VALUE!; #VALUE!; #VALUE!; #VALUE!; 22; 6; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; 1; 3; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!})
and returns
{FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}.
Step 8 - Replace TRUE with the corresponding character
The Boolean value FALSE will be replaced with a "|" character.
IF(ISERROR(SEARCH(MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ")), MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "|")
becomes
IF({FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}, MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "|")
becomes
IF({FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}, {"A"; "B"; "C"; "-"; "1"; "2"; " "; "V"; "F"; " "; "1"; "2"; " "; "5"; "6"; " "; "1"; "2"; " "; "a"; "C"; " "; "1"; "2"; " "; "9"; "0"}, "|")
and returns
{"|";"|";"|";"-";"1";"2";" ";"|";"|";" ";"1";"2";" ";"5";"6";" ";"1";"2";" ";"|";"|";" ";"1";"2";" ";"9";"0"}.
Step 9 - Concatenate characters
The TEXTJOIN function concatenates cell values.
TEXTJOIN(delimiter, ignore_empty, text1, [text2], ...)
TEXTJOIN(, TRUE, IF(ISERROR(SEARCH(MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "ABCDEFGHIJKLMNOPQRSTUVWXYZ")), MID(B3, ROW(A1:INDEX(A:A, LEN(B3))), 1), "|"))
becomes
TEXTJOIN(, TRUE, {"|";"|";"|";"-";"1";"2";" ";"|";"|";" ";"1";"2";" ";"5";"6";" ";"1";"2";" ";"|";"|";" ";"1";"2";" ";"9";"0"})
and returns "|||-12 || 12 56 12 || 12 90".
Excel 365 dynamic array formula in cell B6:
9. Substitute all numbers with a given character/string
Array formula in cell
Read section 8 for an formula explanation.
10. Substitute all characters except numbers and letters
The image above demonstrates an array formula that replaces all characters except upper and lower letters and digits to a given string, in this example |.
Array formula in cell B6:
Read section 8 for a formula explanation.
11. SUBSTITUTE function based on table
The formula in cell C3 substitutes the value in cell B3 using the table in cells E2:F5. This formula works if only one string is found, it returns a blank if nothing is found.
Array formula in cell C3:
Explaining formula
Step 1 - Search for each old string in the table simultaneously
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.
SEARCH(find_text,within_text, [start_num])
SEARCH($E$3:$E$5, B3)
becomes
SEARCH({"red";"yellow";"blue"},"A red fox")
and returns {3; #VALUE!; #VALUE!}. This means that the first value "red" in the array is found at character position 3 in "A red fox".
Step 2 - Find errors
The ISNUMBER function returns TRUE if a value is a number.
ISNUMBER(value)
ISNUMBER(SEARCH($E$3:$E$5, B3))
becomes
ISNUMBER({3; #VALUE!; #VALUE!})
and returns {TRUE; FALSE; FALSE}.
Step 3 - Substitute strings
SUBSTITUTE(B3, $E$3:$E$5, $F$3:$F$5)
becomes
SUBSTITUTE("A red fox",{"red"; "yellow"; "blue"},{"brown"; "pink"; "black"})
and returns
{"A brown fox"; "A red fox"; "A red fox"}.
Step 4 - Replace TRUE with the corresponding value
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(ISNUMBER(SEARCH($E$3:$E$5, B3)), SUBSTITUTE(B3, $E$3:$E$5, $F$3:$F$5), "")
becomes
IF({TRUE; FALSE; FALSE}, {"A brown fox"; "A red fox"; "A red fox"}, "")
and returns
{"A brown fox"; ""; ""}.
Step 5 - Concatenate strings
The TEXTJOIN function concatenates cell values.
TEXTJOIN(delimiter, ignore_empty, text1, [text2], ...)
TEXTJOIN("", TRUE, IF(ISNUMBER(SEARCH($E$3:$E$5, B3)), SUBSTITUTE(B3, $E$3:$E$5, $F$3:$F$5), ""))
becomes
TEXTJOIN("", TRUE, {"A brown fox"; ""; ""})
and returns "A brown fox".
12. How to substitute double quotes
This example demonstrates how to substitute double quotes in a given cell value, this specific example removes the double quotes all together, however, you can easily specify a value you want instead of the double quotes.
Formula in cell C3:
Cell B3 contains Hello "world"!, the formula in cell C3 removes the double quotes so the string becomes: Hello world!
13. Function not working
The SUBSTITUTE function returns
- #NAME? error if you misspell the function name.
- propagates errors, meaning that if the input contains an error (e.g., #VALUE!, #REF!), the function will return the same error.
13.1 Troubleshooting the error value
When you encounter an error value in a cell a warning symbol appears, displayed in the image above. Press with mouse on it to see a pop-up menu that lets you get more information about the error.
- The first line describes the error if you press with left mouse button on it.
- The second line opens a pane that explains the error in greater detail.
- The third line takes you to the "Evaluate Formula" tool, a dialog box appears allowing you to examine the formula in greater detail.
- This line lets you ignore the error value meaning the warning icon disappears, however, the error is still in the cell.
- The fifth line lets you edit the formula in the Formula bar.
- The sixth line opens the Excel settings so you can adjust the Error Checking Options.
Here are a few of the most common Excel errors you may encounter.
#NULL error - This error occurs most often if you by mistake use a space character in a formula where it shouldn't be. Excel interprets a space character as an intersection operator. If the ranges don't intersect an #NULL error is returned. The #NULL! error occurs when a formula attempts to calculate the intersection of two ranges that do not actually intersect. This can happen when the wrong range operator is used in the formula, or when the intersection operator (represented by a space character) is used between two ranges that do not overlap. To fix this error double check that the ranges referenced in the formula that use the intersection operator actually have cells in common.
#SPILL error - The #SPILL! error occurs only in version Excel 365 and is caused by a dynamic array being to large, meaning there are cells below and/or to the right that are not empty. This prevents the dynamic array formula expanding into new empty cells.
#DIV/0 error - This error happens if you try to divide a number by 0 (zero) or a value that equates to zero which is not possible mathematically.
#VALUE error - The #VALUE error occurs when a formula has a value that is of the wrong data type. Such as text where a number is expected or when dates are evaluated as text.
#REF error - The #REF error happens when a cell reference is invalid. This can happen if a cell is deleted that is referenced by a formula.
#NAME error - The #NAME error happens if you misspelled a function or a named range.
#NUM error - The #NUM error shows up when you try to use invalid numeric values in formulas, like square root of a negative number.
#N/A error - The #N/A error happens when a value is not available for a formula or found in a given cell range, for example in the VLOOKUP or MATCH functions.
#GETTING_DATA error - The #GETTING_DATA error shows while external sources are loading, this can indicate a delay in fetching the data or that the external source is unavailable right now.
13.2 The formula returns an unexpected value
To understand why a formula returns an unexpected value we need to examine the calculations steps in detail. Luckily, Excel has a tool that is really handy in these situations. Here is how to troubleshoot a formula:
- Select the cell containing the formula you want to examine in detail.
- Go to tab “Formulas” on the ribbon.
- Press with left mouse button on "Evaluate Formula" button. A dialog box appears.
The formula appears in a white field inside the dialog box. Underlined expressions are calculations being processed in the next step. The italicized expression is the most recent result. The buttons at the bottom of the dialog box allows you to evaluate the formula in smaller calculations which you control. - Press with left mouse button on the "Evaluate" button located at the bottom of the dialog box to process the underlined expression.
- Repeat pressing the "Evaluate" button until you have seen all calculations step by step. This allows you to examine the formula in greater detail and hopefully find the culprit.
- Press "Close" button to dismiss the dialog box.
There is also another way to debug formulas using the function key F9. F9 is especially useful if you have a feeling that a specific part of the formula is the issue, this makes it faster than the "Evaluate Formula" tool since you don't need to go through all calculations to find the issue.
- Enter Edit mode: Double-press with left mouse button on the cell or press F2 to enter Edit mode for the formula.
- Select part of the formula: Highlight the specific part of the formula you want to evaluate. You can select and evaluate any part of the formula that could work as a standalone formula.
- Press F9: This will calculate and display the result of just that selected portion.
- Evaluate step-by-step: You can select and evaluate different parts of the formula to see intermediate results.
- Check for errors: This allows you to pinpoint which part of a complex formula may be causing an error.
The image above shows cell reference B6 converted to hard-coded value using the F9 key. The SUBSTITUTE function requires non-error values which is not the case in this example. We have found what is wrong with the formula.
Tips!
- View actual values: Selecting a cell reference and pressing F9 will show the actual values in those cells.
- Exit safely: Press Esc to exit Edit mode without changing the formula. Don't press Enter, as that would replace the formula part with the calculated value.
- Full recalculation: Pressing F9 outside of Edit mode will recalculate all formulas in the workbook.
Remember to be careful not to accidentally overwrite parts of your formula when using F9. Always exit with Esc rather than Enter to preserve the original formula. However, if you make a mistake overwriting the formula it is not the end of the world. You can “undo” the action by pressing keyboard shortcut keys CTRL + z or pressing the “Undo” button
13.3 Other errors
Floating-point arithmetic may give inaccurate results in Excel - Article
Floating-point errors are usually very small, often beyond the 15th decimal place, and in most cases don't affect calculations significantly.
Useful links
SUBSTITUTE function - Microsoft
SUBSTITUTE function
'SUBSTITUTE' function examples
This blog article describes how to split strings in a cell with space as a delimiting character, like Text to […]
Table of Contents Count cells containing text from list Count entries based on date and time Count cells with text […]
Table of Contents Extract first word in cell value Extract the first word in cell - return warning if not […]
Functions in 'Text' category
The SUBSTITUTE function function is one of 29 functions in the 'Text' category.
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.
Contact Oscar
You can contact me through this contact form