Author: Oscar Cronquist Article last updated on October 06, 2022

TEXTSPLIT function example

The TEXTSPLIT function lets you split a string into an array across columns and rows based on delimiting characters.

Formula in cell E3:

=TEXTSPLIT(B3, ",",";")

The TEXTSPLIT function is available to Excel 365 users.

1. TEXTSPLIT Function Syntax

TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty])

Back to top

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.

Back to top

3. TEXTSPLIT Function example

TEXTSPLIT function example1

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:

TEXTSPLIT(B3," ",".",TRUE)

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}

Back to top

3.1 TEXTSPLIT function - remove #N/A errors

TEXTSPLIT function na error

You can use the IFNA function to remove possible #N/A errors.

Formula in cell E4:

=IFNA(TEXTSPLIT(B3," ",".",TRUE),"")

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(valuevalue_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","","","","","","","","","","","","","",""}

Back to top

3.2 TEXTSPLIT function - pad each value with a given string

TEXTSPLIT function pad with

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:

=TRIM(TEXTSPLIT(B3," ",".",TRUE," "))

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","","","","","","","","","","","","","",""}

Back to top

4. Split string using multiple delimiting characters

TEXTSPLIT function 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}

Back to top

5. How to create a string containing column and row delimiting characters

TEXTSPLIT function create string

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.

  1. Double press with the left mouse button on cell B10, a prompt appears.
  2. Type = (equal sign)
  3. Select the cell range, in this example cell range B3:J8.
  4. Press F9 to convert the cell reference to constants.
  5. Remove the equal sign and the curly brackets { }.
  6. Press Enter.

My regional settings return a comma for a column delimiting character and a semicolon for a row delimiting character.

Back to top

6. How to split dates

TEXTSPLIT function 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:

=TEXTSPLIT(TEXT(B3, "mm/dd/yyyy"), "/")

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(valueformat_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"}.

Back to top

7. Move values to the left if cell is empty as far as possible

TEXTSPLIT function Move values to the left

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.

TEXTSPLIT function Move values to the left1

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:

=TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",";",TRUE,"")

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(delimiterignore_emptytext1[text2], ...)

TEXTJOIN(",",,B3:K13)

Step 2 - Split string ignoring blank values

TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",";",TRUE,"")

Back to top

8. Move values to fill empty cells

TEXTSPLIT function 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:

=WRAPROWS(TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",,TRUE,""),9,"")

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(delimiterignore_emptytext1[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(vectorwrap_count, [pad_with])

WRAPROWS(TEXTSPLIT(TEXTJOIN(",",,B3:K13),",",,TRUE,""),9,"")

Back to top