The LEN string function returns the number of characters, instead of the number of bytes, of the specified string expression, excluding trailing blanks. To get the number of bytes of an expression, the DATALENGTH system function is used. The syntax of the LEN string function is as follows:
LEN ( <string_expression> )
The <string_expression> parameter of the LEN string function is the string expression to be evaluated and can be any data type that can be implicitly converted to VARCHAR.
Here are a few uses of the LEN string function:
Usage #1 : Count the Occurrence of a Character in a String Value
DECLARE @Input VARCHAR(50) = 'SHE SELLS SEASHELLS AT THE SEASHORE'
DECLARE @Char CHAR(1) = 'S'
SELECT LEN(@Input) - LEN(REPLACE(@Input, @Char, '')) AS [CharCount]
CharCount
-----------
8
Usage #2 : Count the Occurrence of a String in a String Value
DECLARE @Input VARCHAR(50) = 'I SCREAM, YOU SCREAM, WE ALL SCREAM FOR ICE CREAM'
DECLARE @String VARCHAR(10) = 'SCREAM'
SELECT (LEN(@Input) - LEN(REPLACE(@Input, @String, ''))) / LEN(@String) AS [StringCount]
StringCount
-------------
3
Usage #3 : Count the Number of Words in a String or Sentence
DECLARE @Input VARCHAR(50) = 'THE QUICK BROWN FOX JUMPS OVER THE LAZY DOG'
SELECT LEN(@Input) - LEN(REPLACE(@Input, ' ', '')) + 1 AS [WordCount]
-- Note: This will only work if each word is separated only by 1 space.
WordCount
-----------
9
Usage #4 : Determine the Row with the Longest Length in a String Column
SELECT TOP 1 *
FROM [dbo].[Product]
ORDER BY LEN([Description]) DESC
Usage #5 : Determine if a String has Trailing Spaces
DECLARE @Input VARCHAR(100) = 'Hello World '
SELECT CASE WHEN LEN(@Input + '*') - 1 != LEN(@Input)
THEN 'With Trailing Spaces'
ELSE 'No Trailing Spaces'
END AS [HasTrailingSpaces]
HasTrailingSpaces
-------------------
With Trailing Spaces
Usage #6 : Count the Length of a String Including Trailing Spaces
DECLARE @Input VARCHAR(100) = 'Hello World '
SELECT LEN(@Input + '*') - 1 AS [StringLength]
StringLength
--------------
16