March 23, 2015 at 9:16 am
I have data like below
Potter, James J
Williams, Ted R
Allen, Gary G
I want to remove Middle Name from the output
Potter, James
Williams, Ted
Allen, Gary
My Query:
SELECT
CASE WHEN CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1) > 0 THEN
REPLACE(Supervisor, SUBSTRING(Supervisor, CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1), LEN(Supervisor)), '')
ELSE Supervisor END AS NewSupervisor from data d
However, I stumble when Middle Name exists somewhere in the name as Replace function repalces every occurrence of the string. For ex: "Allen, Gary G" becomes "Allen,ary"
Do we have any way to say sql to replace after certain index?
March 23, 2015 at 9:29 am
I think I may better use Left in stead of Replace
SELECT
CASE WHEN CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1) > 0 THEN
LEFT(Supervisor, CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1))
ELSE Supervisor END AS NewSupervisor
FROM data d
March 23, 2015 at 9:34 am
CREATE TABLE #Names (Fullname VARCHAR(50))
INSERT INTO #Names (Fullname)
SELECT 'Potter, James J' UNION ALL
SELECT 'Williams, Ted R' UNION ALL
SELECT 'Allen, Gary G' UNION ALL
SELECT 'Allen, Gary Graham' UNION ALL
SELECT 'Allen, Gary ' UNION ALL
SELECT 'Allen, Gary' UNION ALL
SELECT 'Allen, G'
SELECT
OldFullname = Fullname,
x.[Type],
NewFullname = CASE WHEN [Type] = 0 THEN Fullname ELSE LEFT(Fullname, LEN(Fullname)-2) END
FROM #Names
CROSS APPLY (SELECT [Type] = CASE WHEN Fullname LIKE '%, % [A-Z]' THEN 1 ELSE 0 END) x
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
March 23, 2015 at 9:43 am
sarath.tata (3/23/2015)
I think I may better use Left in stead of ReplaceSELECT
CASE WHEN CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1) > 0 THEN
LEFT(Supervisor, CHARINDEX(' ', Supervisor, CHARINDEX(' ', Supervisor, 0) + 1))
ELSE Supervisor END AS NewSupervisor
FROM data d
-- This too
SELECT
OldSupervisor = Supervisor,
x.[Type],
NewSupervisor = CASE
WHEN [Type] = 0 THEN Supervisor
ELSE LEFT(Supervisor, LEN(Supervisor)-CHARINDEX(' ',REVERSE(Supervisor))) END
FROM #data
CROSS APPLY (SELECT [Type] = CASE WHEN RTRIM(Supervisor) LIKE '%, % %' THEN 1 ELSE 0 END) x
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply