How to use the TEXTSPLIT function
The TEXTSPLIT function lets you split a string into an array across columns and rows based on delimiting characters.
Formula in cell E3:
The TEXTSPLIT function is available to Excel 365 users.
Table of Contents
- TEXTSPLIT Function Syntax
- TEXTSPLIT Function Arguments
- TEXTSPLIT Function example
- Split string using multiple delimiting characters
- How to create a string containing column and row delimiting characters
- How to split date value
- Rearrange values to the left if the cell is empty as far as possible
- Rearrange values to fill empty cells
- Get Excel *.xlsx file
1. TEXTSPLIT Function Syntax
TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty])
2. TEXTSPLIT Function Arguments
Input_Text | Required. The original string. |
col_delimiter | Required. The delimiter characters to use, splits the string into columns. |
 [row_delimiter] | Optional. The delimiter characters the TEXTSPLIT function uses to split the string into rows. |
[Ignore_Empty] | Optional. Default value is FALSE. TRUE creates an empty value if the space between delimiting characters is empty. |
[pad_with] | Optional. A string to use, the string is concatenated to each value in the array. The default value is nothing. |
3. TEXTSPLIT Function example
The formula in cell B6 splits the text string in cell B3 based on a space character and a dot. This creates an array with a word in each cell. A new sentence is located on a new row.
The array may now contain array values that contain #N/A error values meaning there are no values in that particular location.
Formula in cell E4:
3.0.1 Explaining formula
Step 1 - TEXTSPLIT function
TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty], [pad_with])
Step 2 - Populate arguments
input_text - B3
col_delimiter - " "
[row_delimiter] - "."
Step 3 - Evaluate function
TEXTSPLIT(B3," ",".",TRUE)
becomes
TEXTSPLIT("Dui viverra tempor. Phasellus porta orci laoreet condimentum vulputate.
Mauris dignissim odio sit amet ullamcorper lobortis.
Vivamus pulvinar, enim vitae iaculis vehicula, purus sapien interdum tellus, viverra congue diam tortor sed quam.
Pellentesque et pulvinar dolor.
Suspendisse euismod."," ",".",TRUE)
and returns
{"Dui", "viverra", "tempor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "Phasellus", "porta", "orci", "laoreet", "condimentum", "vulputate", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Mauris", "dignissim", "odio", "sit", "amet", "ullamcorper", "lobortis", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Vivamus", "pulvinar, ", "enim", "vitae", "iaculis", "vehicula, ", "purus", "sapien", "interdum", "tellus, ", "viverra", "congue", "diam", "tortor", "sed", "quam"; "
Pellentesque", "et", "pulvinar", "dolor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Suspendisse", "euismod", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A}
3.1 TEXTSPLIT function - remove #N/A errors
You can use the IFNA function to remove possible #N/A errors.
Formula in cell E4:
3.1.1 Explaining formula
Step 1 - Create array
TEXTSPLIT(B3," ",".",TRUE)
returns
{"Dui", "viverra", "tempor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "Phasellus", "porta", "orci", "laoreet", "condimentum", "vulputate", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Mauris", "dignissim", "odio", "sit", "amet", "ullamcorper", "lobortis", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Vivamus", "pulvinar, ", "enim", "vitae", "iaculis", "vehicula, ", "purus", "sapien", "interdum", "tellus, ", "viverra", "congue", "diam", "tortor", "sed", "quam"; "
Pellentesque", "et", "pulvinar", "dolor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Suspendisse", "euismod", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A}
Step 2 - Remove #N/A error values
The IFNA function lets you replace #N/A errors with a given string.
IFNA(value, value_if_na)
IFNA(TEXTSPLIT(B3," ",".",TRUE),"")
becomes
IFNA({"Dui", "viverra", "tempor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "Phasellus", "porta", "orci", "laoreet", "condimentum", "vulputate", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Mauris", "dignissim", "odio", "sit", "amet", "ullamcorper", "lobortis", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Vivamus", "pulvinar, ", "enim", "vitae", "iaculis", "vehicula, ", "purus", "sapien", "interdum", "tellus, ", "viverra", "congue", "diam", "tortor", "sed", "quam"; "
Pellentesque", "et", "pulvinar", "dolor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Suspendisse", "euismod", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A}, "")
and returns
{"Dui","viverra","tempor","","","","","","","","","","","","","";"Phasellus","porta","orci","laoreet","condimentum","vulputate","","","","","","","","","","";"
Mauris","dignissim","odio","sit","amet","ullamcorper","lobortis","","","","","","","","","";"
Vivamus","pulvinar,","enim","vitae","iaculis","vehicula,","purus","sapien","interdum","tellus,","viverra","congue","diam","tortor","sed","quam";"
Pellentesque","et","pulvinar","dolor","","","","","","","","","","","","";"
Suspendisse","euismod","","","","","","","","","","","","","",""}
3.2 TEXTSPLIT function - pad each value with a given string
You also have the option to pad each value in the array with any string. I will be padding in this example a single space character.
Formula in cell E4:
3.0.1 Explaining formula
Step 1 - TEXTSPLIT function
input_text - B3
col_delimiter - " "
[row_delimiter] - "."
[Ignore_Empty] - Default value is FALSE. TRUE creates an empty value if the space between delimiting characters is empty.
[pad_with] - " "
TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty], [pad_with])
TEXTSPLIT(B3," ",".",TRUE," ")
becomes
TEXTSPLIT("Dui viverra tempor. Phasellus porta orci laoreet condimentum vulputate.
Mauris dignissim odio sit amet ullamcorper lobortis.
Vivamus pulvinar, enim vitae iaculis vehicula, purus sapien interdum tellus, viverra congue diam tortor sed quam.
Pellentesque et pulvinar dolor.
Suspendisse euismod."," ",".",TRUE," ")
and returns
{"Dui","viverra","tempor"," "," "," "," "," "," "," "," "," "," "," "," "," ";"Phasellus","porta","orci","laoreet","condimentum","vulputate"," "," "," "," "," "," "," "," "," "," ";"
Mauris","dignissim","odio","sit","amet","ullamcorper","lobortis"," "," "," "," "," "," "," "," "," ";"
Vivamus","pulvinar,","enim","vitae","iaculis","vehicula,","purus","sapien","interdum","tellus,","viverra","congue","diam","tortor","sed","quam";"
Pellentesque","et","pulvinar","dolor"," "," "," "," "," "," "," "," "," "," "," "," ";"
Suspendisse","euismod"," "," "," "," "," "," "," "," "," "," "," "," "," "," "}
Step 2 - Remove space characters
The TRIM function removes leading and trailing space characters.
TRIM(text)
TRIM(TEXTSPLIT(B3," ",".",TRUE," "))
becomes
TRIM({"Dui","viverra","tempor"," "," "," "," "," "," "," "," "," "," "," "," "," ";"Phasellus","porta","orci","laoreet","condimentum","vulputate"," "," "," "," "," "," "," "," "," "," ";"
Mauris","dignissim","odio","sit","amet","ullamcorper","lobortis"," "," "," "," "," "," "," "," "," ";"
Vivamus","pulvinar,","enim","vitae","iaculis","vehicula,","purus","sapien","interdum","tellus,","viverra","congue","diam","tortor","sed","quam";"
Pellentesque","et","pulvinar","dolor"," "," "," "," "," "," "," "," "," "," "," "," ";"
Suspendisse","euismod"," "," "," "," "," "," "," "," "," "," "," "," "," "," "})
and returns
{"Dui","viverra","tempor","","","","","","","","","","","","","";"Phasellus","porta","orci","laoreet","condimentum","vulputate","","","","","","","","","","";"
Mauris","dignissim","odio","sit","amet","ullamcorper","lobortis","","","","","","","","","";"
Vivamus","pulvinar,","enim","vitae","iaculis","vehicula,","purus","sapien","interdum","tellus,","viverra","congue","diam","tortor","sed","quam";"
Pellentesque","et","pulvinar","dolor","","","","","","","","","","","","";"
Suspendisse","euismod","","","","","","","","","","","","","",""}
4. Split string using multiple delimiting characters
The string in cell B3 contains both dots and semicolons as an end of a sentence. You can use multiple delimiting characters to create a new column or row.
Formula in cell B6:
=TEXTSPLIT(B3," ",{".",";"},TRUE)
4.1 Explaining formula
input_text - B3
col_delimiter - " "
[row_delimiter] - {".",";"}
[Ignore_Empty] - Default value is FALSE. TRUE creates an empty value if the space between delimiting characters is empty.
TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty], [pad_with])
TEXTSPLIT(B3," ",{".",";"},TRUE)
becomes
TEXTSPLIT("Dui viverra tempor. Phasellus porta orci laoreet condimentum vulputate;
Mauris dignissim odio sit amet ullamcorper lobortis.
Vivamus pulvinar, enim vitae iaculis vehicula, purus sapien interdum tellus, viverra congue diam tortor sed quam;
Pellentesque et pulvinar dolor.
Suspendisse euismod;"," ",{".",";"},TRUE)
and returns
{"Dui", "viverra", "tempor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "Phasellus", "porta", "orci", "laoreet", "condimentum", "vulputate", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Mauris", "dignissim", "odio", "sit", "amet", "ullamcorper", "lobortis", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Vivamus", "pulvinar, ", "enim", "vitae", "iaculis", "vehicula, ", "purus", "sapien", "interdum", "tellus, ", "viverra", "congue", "diam", "tortor", "sed", "quam"; "
Pellentesque", "et", "pulvinar", "dolor", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A; "
Suspendisse", "euismod", #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A, #N/A}
5. How to create a string containing column and row delimiting characters
This section describes how to create a string using delimiting characters, based on your regional settings, from a cell range.
The TEXTJOIN function concatenates values from a cell range and is the opposite to the TEXTSPLIT function, however, it can't use delimiting characters for bor columns and rows.
- Double press with the left mouse button on cell B10, a prompt appears.
- Type = (equal sign)
- Select the cell range, in this example cell range B3:J8.
- Press F9 to convert the cell reference to constants.
- Remove the equal sign and the curly brackets { }.
- Press Enter.
My regional settings return a comma for a column delimiting character and a semicolon for a row delimiting character.
6. How to split dates
The formula in cell D3 splits the date specified in cell B3 into an array containing month, day, and year based on the slash character.
You can of course use whatever delimiting character you want, make sure you change the TEXT and TEXTSPLIT function arguments accordingly.
Dynamic array formula in cell D3:
Explaining formula
Step 1 - Create a text string
Excel dates are actually just numbers, to split a date we need to create a text value.
The TEXT function creates text values based on a formatting pattern.
TEXT(value, format_text)
TEXT(B3, "mm/dd/yyyy")
becomes
TEXT(44649, "mm/dd/yyyy")
and returns "03/29/2022".
Step 2 - Split text string
TEXTSPLIT(TEXT(B3, "mm/dd/yyyy"), "/")
becomes
TEXTSPLIT("03/29/2022", "/")
and returns
{"03", "29", "2022"}.
7. Move values to the left if cell is empty as far as possible
The image above shows a cell range containing values and random empty cells, here is how to move values to the left in the cell range as far as possible using a formula.
The TEXTJOIN function adds only one delimiting character to the string, however, there may be multiple instances of the same character. You can not specify a row delimiting character in the TEXTJOIN function.
I have added semicolons to column K to solve this problem, both delimiting characters let the TEXTSPLIT function split values to both columns and rows.
Formula in cell B16:
Explaining formula
Make sure you add a row delimiting character to the right of the last value on each row, it doesn't have to be a semicolon. You can use whatever character you want.
You are allowed to specify the row delimiting character in the TEXTSPLIT function.
Step 1 - Join values in cell range B3:K13
The TEXTJOIN function allows you to combine text strings from multiple cell ranges and also use delimiting characters (optional).
TEXTJOIN(delimiter, ignore_empty, text1, [text2], ...)
TEXTJOIN(",",,B3:K13)
Step 2 - Split string ignoring blank values
TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",";",TRUE,"")
8. Move values to fill empty cells
This example demonstrates a formula that rearranges all values in order to remove blank cells.
Excel 365 dynamic array formula in cell B16:
Explaining formula
Step 1 - Join cell values
The TEXTJOIN function allows you to combine text strings from multiple cell ranges and also use delimiting characters (optional).
TEXTJOIN(delimiter, ignore_empty, text1, [text2], ...)
TEXTJOIN(",",,B3:K13)
Step 2 - Split values to an array
TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",,TRUE,"")
Step 3 - Rearrange array to nine columns
The WRAPROWS function rearranges values from a 1D array to a 2D array.
WRAPROWS(vector, wrap_count, [pad_with])
WRAPROWS(TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",,TRUE,""),9,"")
Useful links
TEXTSPLIT function - Microsoft
'TEXTSPLIT' function examples
This article demonstrates two ways to calculate the number of times each word appears in a given range of cells. […]
This article demonstrates how to convert a range of cells containing strings separated by a delimiter into a range of […]
The formula displayed above in cell range D3:D9 extracts a word based on its position in a cell value. For […]
Functions in 'Text' category
The TEXTSPLIT function function is one of many functions in the 'Text' category.
Excel function categories
Excel categories
2 Responses to “How to use the TEXTSPLIT 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.
please check parameter optional or required?
dang d. khanh,
Which argument?
An argument without brackets is required, an argument with brackets is optional.