February 4, 2015 at 2:05 am
Hi all,
I want to split full name into lastname,FirstName and middlename. Below is scenario:
Name : Pawar, Ramesh S.
Then I want to split as below:
LastName FirstName MidddleName
Pawar Ramesh S
i.e. Upto comma in a string it is last name, after comma till space it is a first name and after space it is a last name.
Please help.
Thanks
Abhas.
February 4, 2015 at 4:20 am
You can read below link article , split function DelimitedSplit8K is there.
http://www.sqlservercentral.com/articles/Tally+Table/72993/
DECLARE @p_str varchar(max)
SET @p_str = 'Pawar, Ramesh S.'
SET @p_str= REPLACE(@p_str,',','')
SELECTpvtTable.[1] AS LastName,
pvtTable.[2] AS FirstName,
pvtTable.[3] AS MidddleName
FROM [dbo].[DelimitedSplit8K](@p_str,'')
PIVOT
(MAX(item)FOR ItemNumber IN ([1],[2],[3]))
As pvtTable
February 4, 2015 at 5:37 am
SELECT
d.Fullname,
Lastname = LEFT(d.Fullname, pos1-2), -- -2 removes the comma, could use REPLACE
FirstName = SUBSTRING(d.Fullname, pos1+1, (pos2-pos1)-1),
MidddleName = SUBSTRING(d.Fullname,pos2+1,8000), -- could use REPLACE to remove period
x1.*, x2.* -- included for clarity
FROM (SELECT Fullname = 'Pawar, Ramesh S.') d
CROSS APPLY (SELECT pos1 = CHARINDEX(' ', Fullname, 1)) x1
CROSS APPLY (SELECT pos2 = CHARINDEX(' ', Fullname, pos1+1)) x2
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
February 4, 2015 at 5:53 am
It depends on if all the data is exactly formatted like the one example.
i'd lean more towards splitting the data, and not assuming there are three parts every time.
changing the select to have something without a first and second space in it gives a substring error function.
Msg 537, Level 16, State 2, Line 1
Invalid length parameter passed to the LEFT or SUBSTRING function.
SELECT
d.Fullname,
Lastname = LEFT(d.Fullname, pos1-2), -- -2 removes the comma, could use REPLACE
FirstName = SUBSTRING(d.Fullname, pos1+1, (pos2-pos1)-1),
MidddleName = SUBSTRING(d.Fullname,pos2+1,8000), -- could use REPLACE to remove period
x1.*, x2.* -- included for clarity
FROM (SELECT Fullname = 'Pawar, Ramesh S.' UNION ALL SELECT 'Damon, Matt') d
CROSS APPLY (SELECT pos1 = CHARINDEX(' ', Fullname, 1)) x1
CROSS APPLY (SELECT pos2 = CHARINDEX(' ', Fullname, pos1+1)) x2
this is what i think is a little better solution
/*--Results
Fullname Item Item Item
Pawar, Ramesh S. Pawar, Ramesh S.
Damon, Matt Damon, Matt NULL
Madonna Madonna NULL NULL
*/
SELECT
d.Fullname,
Lastname = x1.Item, -- -2 removes the comma, could use REPLACE
FirstName = x2.Item,
MidddleName = x3.Item -- could use REPLACE to remove period
--x1.*, x2.* -- included for clarity
FROM (SELECT Fullname = 'Pawar, Ramesh S.' UNION ALL SELECT 'Damon, Matt' UNION ALL SELECT 'Madonna') d
OUTER APPLY (SELECT Item FROM dbo.DelimitedSplit8K(Fullname,' ') WHERE ItemNumber = 1) x1
OUTER APPLY (SELECT Item FROM dbo.DelimitedSplit8K(Fullname,' ') WHERE ItemNumber = 2) x2
OUTER APPLY (SELECT Item FROM dbo.DelimitedSplit8K(Fullname,' ') WHERE ItemNumber = 3) x3
Lowell
February 4, 2015 at 6:37 pm
Isn't this what PARSENAME is for?
WITH SampleData AS
(
SELECT Fullname = 'Pawar, Ramesh S.' UNION ALL SELECT 'Damon, Matt'
)
SELECT *
,LastName = REVERSE(PARSENAME(MyFullName, 1))
,FirstName = REVERSE(PARSENAME(MyFullName, 2))
,MiddleInitial = REVERSE(PARSENAME(MyFullName, 3))
FROM SampleData a
CROSS APPLY
(
SELECT MyFullName=REPLACE(REPLACE(REPLACE(REVERSE(FullName), '.', ''), ' ', '.'), ',', '')
) b;
๐
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply