October 17, 2019 at 1:38 am
Suppose I had a list of names and one of the names was Kathy Harrison. Notice the double space after the first name. In Excel there is a function called TRIM which could remove extraneous spaces. I am trying to find something like that in SQL. As far as I know, in SQL, TRIM is used for characters other than spaces. The LTRIM and RTRIM functions are used for leading and trailing spaces.
So how would you remove a double or triple space between a first and last name.
October 17, 2019 at 2:06 am
use REPLACE
October 17, 2019 at 2:38 am
As far as I know, in SQL, TRIM is used for characters other than spaces.
Oh no it isn't. TRIM() is the equivalent of LTRIM(RTRIM()) and thus removes leading and trailing spaces.
But to replace an arbitrary number of multiple consecutive spaces with a single space, you can use the infamous triple REPLACE trick:
DECLARE @SomeText VARCHAR(500) = 'this text has random multiple spaces';
SELECT Original = @SomeText
,Fixed = REPLACE(REPLACE(REPLACE(@SomeText, ' ', '<>'), '><', ''), '<>', ' ');
The absence of evidence is not evidence of absence
- Martin Rees
The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
- Phil Parkin
October 17, 2019 at 5:05 am
Phil,
I got the REPLACE stuff to work consistently correctly only if I looped (yep, dirty word) until all the double spaces were replaced. For example, if the input string had a triple-space in it, and I replaced only double with single, I still had a double-space left in my final string. Am I just doing it wrong?
If I did something horrid like use a WHILE loop and tested for the existence of a double-space, it worked a champ. Is there an easy way around this?
thanks (and sorry for sort of hijacking the thread).
October 17, 2019 at 12:29 pm
Am I just doing it wrong?
I think so! If you try plugging a string containing a triple space into my example above, you will see that it gets condensed to a single space.
The absence of evidence is not evidence of absence
- Martin Rees
The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
- Phil Parkin
October 17, 2019 at 2:27 pm
This is so cool !
Thanks for sharing
October 21, 2019 at 1:36 am
The most efficient method for reducing any number of spaces up to 8000 that I've ever seen is as follows...
SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
SomeStringColumn COLLATE LATIN1_GENERAL_BIN,
,' ',' ')
,' ',' ')
,' ',' ')
,' ',' ')
,' ',' ')
,' ',' ')
,' ',' ')
FROM dbo.SomeTable
;
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply