Feeds:
Posts
Comments

Posts Tagged ‘RTRIM’

Removing the last character in a string has never been easier before SQL Server 2022 version. I had written a detailed article back in 2013 regarding this issue, where I used, STUFF(), LEN() functions etc.

In SQL Server 2022, a new enhancement came in TRIM() & RTRIM() function, where we can define any characters to be removed from the String. I had written a detailed article about it earlier. By using above mentioned functions, we can simply remove the last character from the string.

Compatibility Level:

Database compatibility level MUST be 160 or higher to use New Approaches. Given below is the query to change your database compatibility level.


ALTER DATABASE AdventureWorks
SET COMPATIBILITY_LEVEL = 160 

Let me demonstrate, how to remove last character from string in the following examples.

Example 1:

  • Old Approach:

In the old approach, we have to use multiple functions (STUFF()LEN()) in order to remove the last character from string as shown below.

DECLARE @String as VARCHAR(50);
SET @String = 'KenSanchez@gmail.com;';
 
SELECT @String AS String
     , STUFF(@String,LEN(@String), 1, '') AS LastCharacterRemoved;
GO
--OUTPUT

  • New Approach:
  • Using TRIM() function :

In the new approach, its quite simple, we can remove the last character from string by using TRIM() function as shown below.

DECLARE @String as VARCHAR(50);
SET @String = 'KenSanchez@gmail.com;';
 
SELECT @String AS String
     , TRIM(TRAILING';' FROM @String) AS LastCharacterRemoved;
GO
--OUTPUT

  • Using RTRIM() function:

In the new approach, we can remove the last character from string by using RTRIM() function as shown below.

DECLARE @String as VARCHAR(50);
SET @String = 'KenSanchez@gmail.com;';
 
SELECT @String AS String
     , RTRIM(@String,';') AS LastCharacterRemoved;
GO
--OUTPUT

Example 2:

  • Old Approach:

In the old approach, we had to use multiple functions (STUFF(), LEN()) in order to remove the last character from string as shown below.

USE Northwind
GO

SELECT EmployeeID
     , FirstName
     , LastName
     , Title
     , TitleOfCourtesy
     , STUFF(TitleOfCourtesy 
     , LEN(TitleOfCourtesy), 1, '') AS LastCharacterRemoved
FROM Employees;
GO
--OUTPUT

  • New Approach:
  • Using TRIM() function:

In the new approach, its quite simple, we can remove the last character from string by using TRIM() function as shown below.

USE Northwind
GO

SELECT EmployeeID
     , FirstName
     , LastName
     , Title
     , TitleOfCourtesy 
     , TRIM(TRAILING '.' FROM TitleOfCourtesy) AS LastCharacterRemoved 
FROM Employees;
GO
--OUTPUT

  • Using RTRIM() function:

In the new approach, we can remove the last character from string by using RTRIM() function as shown below.

USE Northwind
GO

SELECT EmployeeID
	 , FirstName
	 , LastName
	 , Title
	 , TitleOfCourtesy 
	 , RTRIM(TitleOfCourtesy,'.') AS LastCharacterRemoved
FROM Employees;
GO
--OUTPUT

Conclusion:

In SQL Server 2022 or above, removing the last character from the string is quite easy, since there are multiple functions available to achieve it as shown above. Do let me know which approach are you using and how did you find it.

Read Full Post »

LTRIM and RTRIM are very useful functions when it comes to trim the left side or right side of the string spaces respectively but if you need to trim spaces from both sides , you need to create a user defined function. Here is the script of user defined function. I have been using these built-in and user defined functions for a long time. But a  few days ago, when I was migrating the data from legacy system to our new system, I came across with an issue i.e., I had to trim not only the spaces but also the characters as well.

Given below is the solution :

Left Trim :
Given below is the solution that can help you to trim(remove) the spaces and characters from the LEFT side of the string.

CREATE FUNCTION dbo.L_TRIM(@String VARCHAR(MAX), @Char varchar(5))
RETURNS VARCHAR(MAX)
BEGIN
RETURN SUBSTRING(@String,PATINDEX('%[^' + @Char + ' ]%'
,@String),DATALENGTH(@String))
END
GO
--In this example, the user defined function will remove spaces
--and * from the left side of the string
SELECT '  **  THIS IS A TEST STRING  ***  '
AS [String before Left trim]
, dbo.L_TRIM('  **  THIS IS A TEST STRING  ***  ','*')
AS [String After Left trim]
GO
--In this example, the user defined function will remove spaces
--and 0 from the left side of the string
SELECT ' 0001234' AS [String before Left trim]
, dbo.L_TRIM(' 0001234','0')  [String After Left trim]
GO
--OUTPUT

lefttrim1.1

Right Trim :
Given below is the solution that can help you to trim(remove) the spaces and characters from the RIGHT side of the string.

CREATE FUNCTION dbo.R_TRIM(@String VARCHAR(MAX), @Char varchar(5))
RETURNS VARCHAR(MAX)
BEGIN
RETURN REVERSE(SUBSTRING(REVERSE(@String)
,PATINDEX('%[^' + @Char + ' ]%'
,REVERSE(@String)),DATALENGTH(@String)))
END
GO
SELECT '  **  THIS IS A TEST STRING  ***'
AS [String before Right trim]
, dbo.R_TRIM('  **  THIS IS A TEST STRING  ***  ','*')
AS [String after Right trim]
GO
SELECT '12340000 ' AS [String before Right trim]
, dbo.R_TRIM('12340000 ','0') AS [String after Right trim]
GO
--OUTPUT

righttrim1.2

Trim :
Given below is the solution that can help you to trim(remove) the spaces and characters from the BOTH sides of the string.

CREATE FUNCTION dbo.TRIM(@String VARCHAR(MAX), @Char varchar(5))
RETURNS VARCHAR(MAX)
BEGIN
RETURN SUBSTRING(@String,PATINDEX('%[^' + @Char + ' ]%',@String)
,(DATALENGTH(@String)+2 - (PATINDEX('%[^' + @Char + ' ]%'
,REVERSE(@String)) + PATINDEX('%[^' + @Char + ' ]%',@String)
)))
END
GO
SELECT '  **  THIS IS A TEST STRING  ***  '
AS [String before trim]
, dbo.TRIM('  **  THIS IS A TEST STRING  ***  ','*')
AS [String after trim]
GO
SELECT ' 000012340000 ' AS [String before trim]
, dbo.TRIM(' 000012340000 ','0') AS [String after trim]
GO
--OUTPUT

trim1.3

Read Full Post »