LTRIM RTRIM doesn’t always work






4.92/5 (10 votes)
LTRIM and RTRIM don't always remove all the whitespace characters in a field such as carriage return or linefeed
It is a frequent occurrence that we must remove leading and trailing whitespaces from a
string
before additional processing or sending it to another layer in an application. We can’t always control how the data is entered. The data might come from another system, a data conversion, an old application, EDI, Excel, or from an application which had poor quality control. In some of those cases, a whitespace might not be entered or saved in the system as character 32 which is a whitespace entered in a keyboard. If that happens, SQL built in functions for trimming whitespaces do not work so it becomes necessary to replace the “other” whitespace characters with character 32. Then LTRIM and RTRIM will work as expected.
I created this simple UDF to cleanup the data when necessary. I only use this when troubleshooting an old SQL 2000 application or pinpointing weird data coming into the Data Warehouse from the ERP.
Sample Usage
This example fixes all the product codes which have non printing white spaces. It runs the udf twice but you only touch the codes which need to be changed.Update tblProduct
set ProductCode = dbo.udfTrim(ProductCode)
where Len(ProductCode) != Len(dbo.udfTrim(ProductCode))
The UDF
/*
SQL 2000 Version
2/2/2012 CValenzuela
UDF to really trim the white spaces.
When users copy and paste from Word, Excel, or some other application
into a text box, the special non printing whitespace characters
like a line feed remain. This will replace all the non printing
whitespace characters with Character 32 which is the space bar then
perform an LTRIM and RTRIM
Declare
@Seed as varchar(20),
@Test as varchar(50)
Set @Seed= ' CValenzuela';
Set @Test = CHAR(0)+CHAR(9)+CHAR(10)+CHAR(11)+CHAR(12)+CHAR(13)+CHAR(14)+CHAR(160) + @Seed + CHAR(0)+CHAR(9)+CHAR(10)+CHAR(11)+CHAR(12)+CHAR(13)+CHAR(14)+CHAR(160)
Select
@Seed as Seed,
LTRIM(RTRIM(@SEED)) as Seed_Trimmed,
@Test as Test,
LTRIM(RTRIM(@Test)) as Test_Trimmed,
dbo.udfTrim(@Test) as Test_Trimmed2,
Len(@Seed) as Seed_Length,
DataLength(@Seed) as Seed_DataLength,
LEN(LTRIM(RTRIM(@Seed))) as Seed_Trimmed_Length,
DataLength(LTRIM(RTRIM(@Seed))) as Seed_Trimmed_DataLength,
Len(@Test) as Test_Length,
LEN(LTRIM(RTRIM(@TEST))) as Test_Trimmed_Length,
DataLength(LTRIM(RTRIM(@TEST))) as Test_Trimmed_DataLength,
LEN(dbo.udfTrim(@Test)) as Test_UDFTrimmed_Length,
DataLength(dbo.udfTrim(@Test)) as Test_UDFTrimmed_DataLength
*/
CREATE FUNCTION [dbo].[udfTrim]
(
@StringToClean as varchar(8000)
)
RETURNS varchar(8000)
AS
BEGIN
--Replace all non printing whitespace characers with Characer 32 whitespace
--NULL
Set @StringToClean = Replace(@StringToClean,CHAR(0),CHAR(32));
--Horizontal Tab
Set @StringToClean = Replace(@StringToClean,CHAR(9),CHAR(32));
--Line Feed
Set @StringToClean = Replace(@StringToClean,CHAR(10),CHAR(32));
--Vertical Tab
Set @StringToClean = Replace(@StringToClean,CHAR(11),CHAR(32));
--Form Feed
Set @StringToClean = Replace(@StringToClean,CHAR(12),CHAR(32));
--Carriage Return
Set @StringToClean = Replace(@StringToClean,CHAR(13),CHAR(32));
--Column Break
Set @StringToClean = Replace(@StringToClean,CHAR(14),CHAR(32));
--Non-breaking space
Set @StringToClean = Replace(@StringToClean,CHAR(160),CHAR(32));
Set @StringToClean = LTRIM(RTRIM(@StringToClean));
Return @StringToClean
END
GO
I hope this helps others maintaining old systems which seem to have gremlins.