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
- Syntax
- Arguments
- 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
- How to create name initials
- Get Excel *.xlsx file
- Split search value using a delimiter and search for each substring
- Function not working
1. Syntax
TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty])
2. 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. 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)
returns {"Dui", "viverra", "tempor", #N/A,... , #N/A}
3.1 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}
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),"")
returns {"Dui","viverra",... ,""}
3.2 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",... ," "}
Step 2 - Remove space characters
The TRIM function removes leading and trailing space characters.
TRIM(text)
TRIM(TEXTSPLIT(B3," ",".",TRUE," "))
returns {"Dui","viverra",... ,""}
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)
returns {"Dui", "viverra", ... , #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,"")
9. How to create name initials
The array formula in cell C3 extracts the first character from first, middle and last name. The formula works fine with more or less names, up to 1000 characters. You can easily edit the formula if you need more letters.
Excel 365 dynamic array formula in cell C3:
Array formula in cell C3:
To enter an array formula, type the formula in a cell then press and hold CTRL + SHIFT simultaneously, now press Enter once. Release all keys.
The formula bar now shows the formula with a beginning and ending curly bracket telling you that you entered the formula successfully. Don't enter the curly brackets yourself.
Explaining formula in cell C3
Step 1 - Split name into characters
The MID function returns characters from a text string based on a start number and the number of characters. The ROW function creates an array in this case that we need to split the text string into characters. The TRIM function removes leading and trailing spaces.
MID(" "&TRIM(B3), ROW($B$1:$B$1000), 1)
becomes
MID(" "&TRIM(B3), {1;2;3;4;5;6;7;8;9; ... ; 1000}, 1)
becomes
MID(" Atticus Esteban Griffith", {1;2;3;4;5;6;7;8;9; ... ; 1000}, 1)
and returns
{" ";"A";"t";"t";"i";"c";"u";"s";" "; "E";"s";"t";"e";"b"; "a";"n";" ";"G";"r"; "i";"f";"f";"i"; "t";"h";""; ... ;""}.
Step 2 - Check if a character is a space (blank)
The IF function replaces space characters with the next character.
IF(MID(" "&TRIM(B3), ROW($B$1:$B$1000), 1)=" ", " "&MID(TRIM(B3), ROW($B$1:$B$1000), 1), "")
returns {" A";""; ... ; ""}
Step 3 - Concatenate characters
The TEXTJOIN function concatenates characters in an array and in this case ignoring empty array values.
TRIM(TEXTJOIN("", TRUE, IF(MID(" "&TRIM(B3), ROW($B$1:$B$1000), 1)=" ", " "&MID(TRIM(B3), ROW($B$1:$B$1000), 1), "")))
becomes
TRIM(" A E G")
The TRIM function removes leading and trailing spaces.
TRIM(" A E G") returns "A E G" in cell C3.
Get excel *.xlsx file
Useful links
TEXTSPLIT function - Microsoft
11. Split search value using a delimiter and search for each sub string
This article demonstrates formulas and a UDF that searches for values in a table based on concatenated values and returns the corresponding values also concatenated.
The example image above shows "anil singh raj" in cell B3, the UDF and formulas split the string in substrings and search for each sub-string in cell range E3:E5. If a match is found the corresponding value in cell range F3:F5 is returned.
The result values are concatenated if multiple values are matching values in cell range E3:E5. "anil" is found in cell E3, the corresponding value is 10. "singh" is found in cell E5, the corresponding value is 30. Value "raj" is found in cell E4 and the corresponding value in cell F4 is 20. The value returned in cell C3 is 10 30 20.
What's on this page
- User defined Function
- Excel 2019 Formula
- Match each substring to a table - Excel 365
- Get the Excel File here
11.1. User defined Function
I have
A1(anil singh raj)
It can be anything Like
A1(singh raj anil)
I want return value in
B1 (10 30 20)
Or
B1(30 20 10)
Or
Lookup array is
D1(anil) E1(10)
D2(raj) E2(20)
D3(singh) E3(30)
I have made a small custom function to split the search string and get the values you are looking for.
11.1.2. User Defined Function Syntax
SearchValues(str, search_col, return_col)
str - Search string
search_col - lookup column
return_col - values to return
11.1.3. UDF Formula
Formula in cell C3:
=SearchValues(B3, $E$3:$E$5, $F$3:$F$5)
11.1.4. User Defined Function - VBA
'Name Function Function SearchValues(str As Range, search_col As Range, return_col As Range) 'Dimension variables and declare data types Dim j As Long, i As Long 'Split text in variable str based on a space character arr = Split(str, " ") 'Save the number of rows in range variable search_col to variable j j = search_col.Rows.CountLarge 'Iterate through all array values in variable arr For Each Vl In arr 'Go from 1 to number stored in variable j For i = 1 To j 'If ... Then statement 'Check if value in range variable search_col is equal to variable Vl 'Concatenate corresponding value in return_col with result variable if true If search_col.Cells(i, 1) = Vl Then result = result & return_col.Cells(i, 1) & " " Next i Next Vl 'Return string stored in result to worksheet SearchValues = result End Function
11.1.5. Where to put the VBA code?
You need to copy the code above and paste it to a code module, detailed instructions below.
- Open vb editor (shortcut keys: Alt+F11)
- Insert a new module
- Paste code to code module
- Exit vb Editor
Note, save your workbook as a macro-enabled workbook *.xlsm to keep the code attached to your workbook.
11.2. Excel 2019 Formula
Array formula in cell C3:
11.2.1 Explaining formula in cell C3
Step 1 - Insert XML tags
The SUBSTITUTE function replaces a specific text string in a value. We need to replace the delimiting character to xml tags in order to split the strings into an array.
SUBSTITUTE(text, old_text, new_text, [instance_num])
"<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>"
returns "<A><B>anil</B><B>singh</B><B>raj</B></A>"
Step 2 - Split string into substrings
The FILTERXML function extracts specific values from XML content by using the given xpath. You can use this function to split a string into substrings.
FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")
returns {"anil";"singh";"raj"}.
Step 3 - Convert a vertical range to a horizontal range, or vice versa
The TRANSPOSE function allows you to convert a vertical range to a horizontal range, or vice versa.
TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B"))
returns {"anil", "singh", "raj"}.
Step 4 - Search for each value in the array in cell range $E$3:$E$5
The SEARCH function returns a number representing the position of character at which a specific text string is found reading left to right.
SEARCH(find_text,within_text, [start_num])
SEARCH(TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")), $E$3:$E$5)
returns {1, #VALUE!, ... , #VALUE!}.
Step 5 - Replace #VALUE errors with 0 (zero)
The IFERROR function lets you catch most errors in Excel formulas.
IFERROR(value, value_if_error)
IFERROR(SEARCH(TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")), $E$3:$E$5), 0)
returns {1, 0, ... , 0}.
Step 6 - Return values if TRUE (1)
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(IFERROR(SEARCH(TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")), $E$3:$E$5), 0), $F$3:$F$5, "")
returns {10,"","";"","",20;"",30,""}.
Step 7 - Convert a vertical range to a horizontal range, or vice versa
The TRANSPOSE function allows you to convert a vertical range to a horizontal range, or vice versa.
TRANSPOSE(IF(IFERROR(SEARCH(TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")), $E$3:$E$5), 0), $F$3:$F$5, ""))
returns {10,"","";"","",30;"",20,""}.
Step 8 - Concate values in array
The TEXTJOIN function allows you to combine text strings from multiple cell ranges and also use delimiting characters if you want.
TEXTJOIN(" ", TRUE, TRANSPOSE(IF(IFERROR(SEARCH(TRANSPOSE(FILTERXML("<A><B>"& SUBSTITUTE(B3, " ", "</B><B>") & "</B></A>", "//B")), $E$3:$E$5), 0), $F$3:$F$5, "")))
returns "10 30 20".
11.3. Lookup each substring in a value and join the result - Excel 365
Excel 365 formula in cell C3:
Explaining formula
Step 1 - Split value into substrings
The TEXTSPLIT function splits a string into an array based on delimiting values.
Function syntax: TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty])
TEXTSPLIT(B3, " ", , TRUE)
returns {"anil","singh","raj"}.
Step 2 - Match values and return the corresponding values
The LOOKUP function find a value in a cell range and return a corresponding value on the same row.
Function syntax: LOOKUP(lookup_value, lookup_vector, [result_vector])
LOOKUP(TEXTSPLIT(B3, " ", , TRUE), $E$3:$E$5, $F$3:$F$5)
returns {10,30,20}.
Step 3 - Join the corresponding values
The TEXTJOIN function combines text strings from multiple cell ranges.
Function syntax: TEXTJOIN(delimiter, ignore_empty, text1, [text2], ...)
TEXTJOIN(" ", TRUE, LOOKUP(TEXTSPLIT(B3, " ", , TRUE), $E$3:$E$5, $F$3:$F$5))
returns "10 30 20".
12. Function not working
The TEXTSPLIT function returns
- #VALUE! error if you use a non-numeric input value in the fourth argument [Ignore_Empty].
- #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.
12.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.
12.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 B3 converted to hard-coded value using the F9 key.
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
12.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.
'TEXTSPLIT' 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 Extract first word in cell value Extract the first word in cell - return warning if not […]
This article demonstrates several techniques to check if a cell contains text based on a list. The first example shows […]
Functions in 'Text' category
The TEXTSPLIT function function is one of 29 functions in the 'Text' category.
Excel function categories
Excel categories
20 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.
Contact Oscar
You can contact me through this contact form
I have some shorter formulas for you...
Initials from first and last names
------------------------------------
=LEFT(TRIM(A2))&" "&MID(TRIM(A2),FIND(" ",TRIM(A2))+1,1)
Initials from first, middle and last names
-----------------------------------------------------------------
=TRIM(LEFT(TRIM(A2))&" "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&" "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99)))&" "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),298,99))))
Create middle name initials
---------------------------------------------------
=CHOOSE(LEN(TRIM(A2))-LEN(SUBSTITUTE(TRIM(A2)," ","")),TRIM(A2),SUBSTITUTE(TRIM(A2)&" "," "&TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99))&" "," "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&". "),SUBSTITUTE(SUBSTITUTE(TRIM(A2)&" "," "&TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99))&" "," "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&". ")," "&TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99))&" "," "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99)))&". "))
My "Initials from first and last names" formula is only 3 characters shorter (taking advantage of the LEFT functions default behavior); however my "Initials from first, middle and last names" formula is about half the size of yours and my "Create middle name initials" formula is a little more than 60% the size of yours.
Rick Rothstein (MVP - Excel),
Great, they worked perfectly!
Thanks for posting!
[...] How to create initials from a list of first, middle and last names [Get Digital help] [...]
Oscar, have I got a treat for you. Assuming that there will never be any cells with more than four names in it, here is an amazingly short formula (considering what has been posted earlier) that I have just come up with...
=LEFT(A2,FIND(" ",A2))&IF(LEN(A2)-LEN(SUBSTITUTE(A2," ",""))>1,LEFT(TRIM(A3))&LEFT(TRIM(MID(SUBSTITUTE(A2," ",REPT(" ",99)),100,99)))&". ","")&IF(LEN(A2)-LEN(SUBSTITUTE(A2," ",""))=3,LEFT(TRIM(MID(SUBSTITUTE(A2," ",REPT(" ",99)),199,99)))&". ","")&TRIM(LEFT(RIGHT(SUBSTITUTE(" "&A2," ",REPT(" ",99)),99),99))
Sorry, I forgot to mention... the formula is for creating middle name initials.
Okay, in addition to the much shorter formula for creating middle name initials that I just posted above, here is a shorter formula for the initials from first, middle, last names as well...
=TRIM(LEFT(A2)&" "&LEFT(TRIM(MID(SUBSTITUTE(A2," ",REPT(" ",99)),100,99)))&" "&LEFT(TRIM(MID(SUBSTITUTE(A2," ",REPT(" ",99)),199,99))))
Rick Rothstein (MVP - Excel),
Thank you for commenting!
I can´t get your formulas working, check out the attached file. Sheet 2 and column C and D.
Initialsv2.xlsx
I suspect wordpress removing characters.
@Oscar,
It looks like I had copied the wrong formula for the "creating middle name initials"... there was an A3 reference that should have been an A2 reference and there was an extra TRIM function call concatenated onto the part displaying the first initial... I remember having fixed both of those before posting, so I must have copied the wrong formula when I created my comment here. Sorry. Fixing those made the formula into the final form I meant to post, but that did not take care of all the problems though, as I did not account for extra leading and trailing spaces around the names (which is why the "initials from first, middle, last names" formula failed as well). Here are the fixed formula which should now work for you (longer than originally intended because of the added TRIM function calls to take care of the leading and trailing spaces, but still noticeably shorter than my previous short formulas from last year)...
Creating middle name initials
-----------------------------------------------------------
=LEFT(TRIM(A2),FIND(" ",TRIM(A2)))&IF(LEN(TRIM(A2))-LEN(SUBSTITUTE(TRIM(A2)," ",""))>1,LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&". ","")&IF(LEN(TRIM(A2))-LEN(SUBSTITUTE(TRIM(A2)," ",""))=3,LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99)))&". ","")&TRIM(LEFT(RIGHT(SUBSTITUTE(" "&TRIM(A2)," ",REPT(" ",99)),99),99))
Initials from first, middle, last names
-----------------------------------------------------------
=TRIM(LEFT(TRIM(A2))&" "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&" "&LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99))))
By the way, I noticed you had array-entered the formulas in the workbook you linked to in your last message... the above formulas do not need to be array-entered, they will work fine when normally entered.
Silly me... I have two occurances in my "Creating middle name initials" formula where I TRIM cell A2 only to then follow do that by removing all the spaces in cell A2. Removing those two unnecessary TRIM function calls shortens the formula by 12 characters without affecting the formulas ultimate action. Here is that revised formula...
=LEFT(TRIM(A2),FIND(" ",TRIM(A2)))&IF(LEN(TRIM(A2))-LEN(SUBSTITUTE(A2," ",""))>1,LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),100,99)))&". ","")&IF(LEN(TRIM(A2))-LEN(SUBSTITUTE(A2," ",""))=3,LEFT(TRIM(MID(SUBSTITUTE(TRIM(A2)," ",REPT(" ",99)),199,99)))&". ","")&TRIM(LEFT(RIGHT(SUBSTITUTE(" "&TRIM(A2)," ",REPT(" ",99)),99),99))
Rick Rothstein (MVP - Excel),
I got your formulas working, thanks for posting!
[…] How to create initials from a list of first, middle and last names [Get Digital help] […]
[…] How to create initials from a list of first, middle and last names [Get Digital help] […]
[…] How to create initials from a list of first, middle and last names [Get Digital help] […]
Thanks
for reply my question
it makes me very easy to do my job more simple
but i am facing a problem
if the value is not in lookup array the result is only partial
I have
A1(anil baljeet raj)
and result should be
B1 (10 (error) 20)
Or
Lookup array is
D1(anil) E1(10)
D2(raj) E2(20)
D3(singh) E3(30)
means if the value is not in the lookup array
the result should not skip the value's(not in the lookup array) space
Does the following UDF do what you want? NOTE that I change the argumemtn list from how Oscar setup his UDF... instead of a second argument for the search column and a third argument for the replacement column, I have only a second argument for the search/replace table (assumed to be two contiguous, aligned ranges of cells); so, you would call my UDF like this...
=SearchValues(A1,$D$1:$E$3)
where cell A1 has the text being parsed and range D1:E3 contains the search and replace values. Here is my UDF code...
Rick Rothstein (MVP - Excel),
Thank you for your comment and yes your UDF works fine. Yours is probably faster too using the Range Find method, but is it faster than converting the range to an array and then search with a simple For - Next? Anyway, interesting UDF.
Anil,
If your search and replace table is not contiguous this UDF seems to work also.
Thank you very much oscar
it makes me very easy to do my work
i hope you will be in touch as you can
for our futures problems regarding excel
thanks Again
with regards
Anil
[…] How to create initials from a list of first, middle and last names [Get Digital help] […]
please check parameter optional or required?
dang d. khanh,
Which argument?
An argument without brackets is required, an argument with brackets is optional.