Returns text that occurs before a given character or string. It is the opposite of the TEXTAFTER function.
Syntax
=TEXTBEFORE(text,delimiter,[instance_num], [match_mode], [match_end], [if_not_found])
The TEXTBEFORE function syntax has the following arguments:
text The text you are searching within. Wildcard characters are not allowed. If text is an empty string, Excel returns empty text. Required.
delimiter The text that marks the point before which you want to extract. Required.
instance_num The instance of the delimiter after which you want to extract the text. By default, instance_num = 1. A negative number starts searching text from the end. Optional.
match_mode Determines whether the text search is case-sensitive. The default is case-sensitive. Optional. Enter one of the following:
-
0 Case sensitive.
-
1 Case insensitive.
match_end Treats the end of text as a delimiter. By default, the text is an exact match. Optional. Enter the following:
-
0 Don't match the delimiter against the end of the text.
-
1 Match the delimiter against the end of the text.
if_not_found Value returned if no match is found. By default, #N/A is returned. Optional.
Remarks
When searching with an empty delimiter value, TEXTBEFORE matches immediately. It returns empty text when searching from the front (if instance_num is positive) and the entire text when searching from the end (if instance_num is negative).
Example |
Result |
---|---|
=TEXTBEFORE("Red riding hood’s, red hood", "hood") |
Red riding |
=TEXTBEFORE("Red riding hood’s, red hood", "") |
|
=TEXTBEFORE("Red riding hood’s, red hood", "", -1) |
Red riding hood’s, red hood |
Errors
-
Excel returns a #VALUE! error if instance_num = 0 or if instance_num is greater than the length of text.
-
Excel returns a #N/A error if delimiter isn’t contained in text.
-
Excel returns a #N/A error if instance_num is greater than the number of occurrences of delimiter in text.
Examples
Copy the example data in each of the following tables and paste it in cell A1 of a new Excel worksheet. If you need to, you can adjust the column widths to see all the data.
Data |
||
Little Red Riding Hood's red hood |
||
Little red Riding Hood's red hood |
||
Formulas |
Results |
|
=TEXTBEFORE(A2,"Red") |
Little |
|
=TEXTBEFORE(A3,"Red") |
#N/A |
|
=TEXTBEFORE(A3,"red",2) |
Little red Riding Hood's |
|
=TEXTBEFORE(A3,"red",-2) |
Little |
|
=TEXTBEFORE(A3,"Red",,FALSE) |
#N/A |
|
=TEXTBEFORE(A3,"red",3) |
#N/A |
Data |
|
Marcus Aurelius |
|
Socrates |
|
Immanuel Kant |
|
Formulas |
Results |
=TEXTBEFORE(A2," ",,,1) |
Marcus |
=TEXTBEFORE(A3," ",,,0) |
#N/A |
=TEXTBEFORE(A3," ",,,1) |
Socrates |
=TEXTBEFORE(A4," ",,,1) |
Immanuel |