How to use the LEN function
What is the LEN function?
The LEN function returns a number representing the total count of characters in a given cell value.
What is the difference between LEN and LENB functions?
The LEN and LENB functions handle character counting differently based on your default language setting in Excel. LENB is designed for double-byte languages like Chinese, Japanese, Korean. It counts each double-byte character as 2 when a DBCS language is set as the default.
LEN always counts each character as 1, single-byte or double-byte, regardless of language setting. So LENB will return larger position values than LEN for the same text in a DBCS language. The difference accounts for the double-byte characters taking 2 positions.
Japanese, Chinese (Simplified), Chinese (Traditional), and Korean are some examples of languages supporting DBCS.
Table of Contents
1. Syntax
LEN(text)
2. Arguments
text | Required. The text string or cell reference you want to count the number of characters in. |
3. Example
The LEN function counts all characters in a given cell. The image above demonstrates the LEN function in column C.
Formula in cell C3:
Cell B3 contains "apple" without the double quotes, the LEN function in cell C3 returns 5 because apple has five characters.
Can I use the LEN function with a cell range?
You can also use a cell range, however, the output is an array of values. You need to enter the formula as an array formula if you use an Excel version earlier than Excel 365, as far as I know.
Array formula in cell D3:D6:
Excel 365 subscribers may enter the formula as a regular formula, the values spill automatically to cells below as far as needed.
4. Count characters based on condition - example 1
This example
Excel 365 dynamic array formula in cell F3:
4.1 Explaining formula
Step 1 - Logical expression
The equal sign lets you compare value to value, you can also compare value to an array of values. The result is an array of boolean values TRUE or FALSE with the same number of items as the original array.
B3:B10=E3
becomes
{"bus"; "boat"; "train"; "airplane"; "bus"; "rocket"; "bike"; "bus"}="bus"
and returns
{TRUE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; TRUE}.
Step 2 - Filter values based on a logical expression
The FILTER function lets you extract values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(C3:C10, B3:B10=E3)
becomes
FILTER({"PFBALWHHGPCVXYFOVIB"; "YDSUDFAQTB"; "LXUUCBSUVGPQQDMFD"; "BAKNRWOTCXXDVX"; "MEXPFTJTIO"; "IWGTPEBOFRLSMQ"; "SDFSTGUOCQS"; "BIJUNKKGJUAYJ"}, {TRUE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; TRUE})
and returns
{"PFBALWHHGPCVXYFOVIB"; "MEXPFTJTIO"; "BIJUNKKGJUAYJ"}.
Step 3 - Count characters in the array, value by value
LEN(FILTER(C3:C10, B3:B10=E3))
becomes
LEN({"PFBALWHHGPCVXYFOVIB"; "MEXPFTJTIO"; "BIJUNKKGJUAYJ"})
and returns
{19; 10; 13}.
Step 4 - Add numbers and return a total
The SUM function calculates a total.
SUM(number1, [number2], ...)
SUM(LEN(FILTER(C3:C10, B3:B10=E3)))
becomes
SUM({19; 10; 13})
and returns 42.
5. Count characters based on condition - example 2
The folllowing fomrula counts values that contain a specific substring specified in cell D3.
Excel 365 dynamic array formula in cell E3:
Cells B4, B5, and B6 all contain the specified substring, their character count is 4,5 and 8 which makes it a total of 17 chararcters.
5.1 Explaining formula
Step 1 - Find string in cell range B3:B10
The SEARCH function returns a number representing the position of the character at which a specific text string is found reading left to right.
SEARCH(find_text,within_text, [start_num])
SEARCH(D3, B3:B10)
becomes
SEARCH("a", {"bus"; "boat"; "train"; "airplane"; "bus"; "rocket"; "bike"; "bus"})
and returns
{#VALUE!; 3; 3; 1; #VALUE!; #VALUE!; #VALUE!; #VALUE!}
Step 2 - Check if number
The ISNUMBER function checks if a value is a number, and returns TRUE or FALSE.
ISNUMBER(value)
ISNUMBER(SEARCH(D3,B3:B10))
becomes
ISNUMBER({#VALUE!; 3; 3; 1; #VALUE!; #VALUE!; #VALUE!; #VALUE!})
and returns
{FALSE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE}.
Step 3 - Filter values
The FILTER function lets you extract values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(B3:B10,ISNUMBER(SEARCH(D3,B3:B10)))
becomes
FILTER(B3:B10,{FALSE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE})
and returns
{"boat"; "train"; "airplane"}.
Step 4 - Count characters
LEN(FILTER(B3:B10,ISNUMBER(SEARCH(D3,B3:B10))))
becomes
LEN({"boat"; "train"; "airplane"})
and returns
{4; 5; 8}.
Step 5 - Add numbers and return a total
The SUM function calculates a total.
SUM(number1, [number2], ...)
SUM(LEN(FILTER(B3:B10, ISNUMBER(SEARCH(D3, B3:B10)))))
becomes
SUM({4; 5; 8})
and returns 17.
6. Count characters based on a list
Excel 365 dynamic array formula in cell F3:
6.1 Explaining formula
Step 1 - Compare the list with values in B3:B10
The COUNTIF function calculates the number of cells that meet a given condition.
COUNTIF(range, criteria)
COUNTIF(E3:E4,B3:B10)
becomes
COUNTIF({"bus"; "bike"},{"bus"; "bike"; "train"; "airplane"; "bus"; "rocket"; "bike"; "bus"})
and returns
{1; 1; 0; 0; 1; 0; 1; 1}.
Step 2 - Filter values based on a logical expression
The FILTER function lets you extract values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(C3:C10, COUNTIF(E3:E4,B3:B10))
becomes
FILTER({"PFBALWHHGPCVXYFOVIB"; "YDSUDFAQTB"; "LXUUCBSUVGPQQDMFD"; "BAKNRWOTCXXDVX"; "MEXPFTJTIO"; "IWGTPEBOFRLSMQ"; "SDFSTGUOCQS"; "BIJUNKKGJUAYJ"}, {1; 1; 0; 0; 1; 0; 1; 1})
and returns
{"PFBALWHHGPCVXYFOVIB"; "YDSUDFAQTB"; "MEXPFTJTIO"; "SDFSTGUOCQS"; "BIJUNKKGJUAYJ"}.
Step 3 - Count characters in the array, value by value
LEN(FILTER(C3:C10, COUNTIF(E3:E4,B3:B10)))
becomes
LEN({"PFBALWHHGPCVXYFOVIB"; "YDSUDFAQTB"; "MEXPFTJTIO"; "SDFSTGUOCQS"; "BIJUNKKGJUAYJ"})
and returns
{19; 10; 10; 11; 13}.
Step 4 - Add numbers and return a total
The SUM function calculates a total.
SUM(number1, [number2], ...)
SUM(LEN(FILTER(C3:C10, COUNTIF(E3:E4,B3:B10))))
becomes
SUM({19; 10; 10; 11; 13})
and returns 63. 19 + 10 + 10 + 11 + 13 equals 63.
7. Count characters in a formula
Does the LEN function count characters in a formula?
The LEN function does not count the number of characters in a formula, however, it counts the number of characters a formula returns.
To count the characters of a formula use the FORMULATEXT function and the LEN function combined.
Formula in cell G7:
7.1 Explaining formula
Step 1 - Extract formula text
The FORMULATEXT function returns the contents of a cell as long as it contains a formula.
FORMULATEXT(reference)
FORMULATEXT(G3)
returns
"=SUM(LEN(FILTER(C3:C10,COUNTIF(E3:E4,B3:B10))))"
Step 2 - Count characters
LEN(FORMULATEXT(G3))
becomes
LEN("=SUM(LEN(FILTER(C3:C10,COUNTIF(E3:E4,B3:B10))))")
and returns 47.
8. Count characters in multiple cell ranges
Formula in cell B12:
7.1 Explaining formula
Step 1 - Join cell ranges vertically
The VSTACK function lets you join cell ranges, it joins data to the first blank cell at the bottom of a cell range or array.
VSTACK(array1,[array2],...)
VSTACK(B3:B9,D3:D9,F3:F9)
becomes
VSTACK({"V"; "OECER"; "PDY"; "GOGA"; 0; 0; 0},{"M"; "KA"; "GXQ"; "SU"; "DH"; "VJ"; "DMX"},{"LXECV"; "OIWH"; "DRM"; "FT"; "SLQ"; 0; 0})
and returns
{"V"; "OECER"; "PDY"; "GOGA"; 0; 0; 0; "M"; "KA"; "GXQ"; "SU"; "DH"; "VJ"; "DMX"; "LXECV"; "OIWH"; "DRM"; "FT"; "SLQ"; 0; 0}
Step 2 - Count characters
LEN((VSTACK(B3:B9,D3:D9,F3:F9))
becomes
LEN({"V"; "OECER"; "PDY"; "GOGA"; 0; 0; 0; "M"; "KA"; "GXQ"; "SU"; "DH"; "VJ"; "DMX"; "LXECV"; "OIWH"; "DRM"; "FT"; "SLQ"; 0; 0})
and returns
{1; 5; 3; 4; 0; 0; 0; 1; 2; 3; 2; 2; 2; 3; 5; 4; 3; 2; 3; 0; 0}.
Step 3 - Add numbers and return a total
The SUM function calculates a total.
SUM(number1, [number2], ...)
SUM(LEN((VSTACK(B3:B9,D3:D9,F3:F9))))
becomes
SUM({1; 5; 3; 4; 0; 0; 0; 1; 2; 3; 2; 2; 2; 3; 5; 4; 3; 2; 3; 0; 0})
and returns 45.
9. Function not working
The LEN function returns
- #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.
9.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.
9.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. The LEN function requires non-error values which is not the case in this example. We have found what is wrong with the formula.
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
9.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.
Useful resources
LEN function - Microsoft support
Count Specific Text in Cell
'LEN' function examples
This post explains how to lookup a value and return multiple values. No array formula required.
This blog article describes how to split strings in a cell with space as a delimiting character, like Text to […]
In this blog post I will demonstrate methods on how to find, select, and deleting blank cells and errors. Why […]
Functions in 'Text' category
The LEN function function is one of 29 functions in the 'Text' category.
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