Summary

The Excel TEXTBEFORE function returns the text that occurs before a given substring or delimiter. In cases where multiple delimiters appear in the text, TEXTBEFORE can return text before the nth occurrence of the delimiter.

Purpose 

Extract text before a delimiter

Return value 

Extracted text string

Syntax

=TEXTBEFORE(text,delimiter,[instance_num],[match_mode],[match_end],[if_not_found])
  • text - The text string to extract from.
  • delimiter - The character(s) that delimit the text.
  • instance_num - [optional] The instance of the delimiter in text. Default is 1.
  • match_mode - [optional] Case-sensitivity. 0 = enabled, 1 = disabled. Default is 0.
  • match_end - [optional] Treat end of text as delimiter. 0 = disabled, 1 = enabled. Default is 0.
  • if_not_found - [optional] Value to return when no match is found. #N/A is default.

How to use 

The TEXTBEFORE function extracts text that occurs before a given delimiter. When multiple delimiters appear in the text, TEXTBEFORE can return text before the nth occurrence of a delimiter. TEXTBEFORE can also extract text that occurs before a given delimiter when counting from the end of a text string (i.e., get the text before the second to the last delimiter).

  • The output from TEXTBEFORE is a single text string that occurs before a matched delimiter.
  • TEXTBEFORE takes six arguments, but only the first two are required: text provides the text to process, and delimiter is the substring used to split the text.
  • The instance_num argument indicates which instance of the delimiter to use. For example, to extract the text before the second instance of a delimiter, use 2 for instance_num. If not supplied, instance_num defaults to 1. 
  • By default, TEXTBEFORE is case-sensitive (match_mode = 0) and will match case when looking for a delimiter. Set match_mode to 1 to ignore case when matching delimiters.
  • By default, TEXTBEFORE will not treat the end of a text string like a delimiter (match_end = 0). To enable this behavior, set match_end to 1.
  • By default, TEXTBEFORE will return #N/A when it cannot find the specified delimiter. To return something other than #N/A, provide a value for if_not_found. Note that when match_end is enabled, it will override the value provided for if_not_found.

Note that Excel has three related functions that split text:

  • Use TEXTSPLIT to extract all text separated by a given delimiter.
  • Use TEXTBEFORE to extract the text before a given delimiter.
  • Use TEXTAFTER to extract the text after a given delimiter.

Basic usage

To extract the text that occurs before a specific character or substring, provide the text and the character(s) to use for delimiter in double quotes (""). For example, to extract the last name from "Jones, Bob", provide a comma in double quotes (",") as delimiter:

=TEXTBEFORE("Jones,Bob",",") // returns "Jones"

Note that you can use more than one character for delimiter. For example to extract the first dimension in the text string "12 ft x 20 ft", use " x "for delimiter:

=TEXTBEFORE("12 ft x 20 ft"," x ") // returns "12 ft"

Note we include the space before and after x since all three characters function as a delimiter.

Text before with a positive instance number

By default instance_num is positive, and TEXTBEFORE will count instances of the delimiter starting from the left, as illustrated in the image below. To get all text before the first space, provide 1 for instance_num. To extract all text before the second space, provide 2. To get all text before the last word in the sentence ("dog") provide 8 for instance_num:

TEXTBEFORE with a positive instance number

The formulas below extract text before the first and second occurrence of a hyphen character ("-"):

=TEXTBEFORE("ABX-112-Red-Y","-",1) // returns "ABX"
=TEXTBEFORE("ABX-112-Red-Y","-",2 // returns "ABX-112"

TEXTBEFORE will return #N/A if the specified instance is not found.

Text before with a negative instance number

One of TEXTBEFORE special powers is that it also supports negative instance numbers, which makes it possible to work backward from the last delimiter. When instance_num is negative, TEXTBEFORE will count delimiters from the right, as seen below. To extract the last word in the sentence ("dog"), you would use -1 for instance number. To extract all text before "lazy", use -2 for instance number, and so on

TEXTBEFORE with a negative instance number

The formulas below extract the text that occurs before the last hyphen and the second to the last hyphen:

=TEXTBEFORE("ABX-112-Red-Y","-",-1) // returns "ABX-112-Red"
=TEXTBEFORE("ABX-112-Red-Y","-",-2) // returns "ABX-112"

If instance_num is out-of-range, TEXTBEFORE returns an #N/A error.

Match end of text

Normally, TEXTBEFORE does not treat the end of a text string as a delimiter. For example, by default, the formula below will return #N/A because there is no fourth delimiter:

=TEXTBEFORE("ABX-123-Red-XYZ","-",4) // returns #N/A

If we enable match_end by providing 1, the formula behaves as if a delimiter exists after "XYZ":

=TEXTBEFORE("ABX-123-Red-XYZ","-",4,,1) // returns "ABX-123-Red-XYZ"

This causes TEXTBEFORE to retrieve the entire text string because the text already contains 3 instances of the delimiter. Take care in situations where a delimiter cannot be found. For example, if match_end is enabled and instance_num is 1, TEXTBEFORE will return the entire string if the delimiter is not found. The video below demonstrates how the match_end argument can be used:

Multiple delimiters

To provide multiple delimiters at the same time to TEXTBEFORE, you can use an array constant like {"x","y"} where x and y represent different delimiters. One use of this feature is to handle inconsistent delimiters in the source text. For example, in the worksheet below, the comma appears with (", ") and without (",") a space character. By providing the array constant {", ",","} for delimiter, both variations are handled correctly:

=TEXTBEFORE(B4,{", ",","})

TEXTBEFORE with more than one delimiter

Case-sensitivity

By default, TEXTBEFORE is case-sensitive when searching for delimiter. This behavior is controlled by the match_mode argumenta boolean value that enables and disables case sensitivity. By default, match_mode is FALSE. In the example below, the delimiter appears as both " x " and " X " (upper and lower case "x"). The formula in D4 sets match_mode to TRUE, which disables case sensitivity and allows TEXTBEFORE to match both versions of the delimiter:

=TEXTBEFORE(B4," x ",,TRUE) // disable case-sensitivity

TEXTBEFORE case sensitive example

Note: You can use 1 and 0 in place of TRUE and FALSE for the match_mode argument.

Notes

  • TEXTBEFORE is case-sensitive by default.
  • TEXTBEFORE will return an #N/A error if delimiter is not found.
  • TEXTBEFORE will return a #VALUE! error if text is empty
  • TEXTBEFORE will return #N/A if instance_num is out-of-range.
Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.