SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Breaking up a string of text


Breaking up a string of text

Author
Message
RedBirdOBX
RedBirdOBX
SSC-Enthusiastic
SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)

Group: General Forum Members
Points: 154 Visits: 243
Hello again,

I have some very dirty data here. I'm working on a Customers table which I plan to clean up and insert into a new table. Currently, the table looks like this:

LastName, FirstName, MiddleInt
-----------------------------------------
Smith,John,Q * *

So "Smith,John,Q" IS the last name and "*" are stored in the First Name and Middle Int fields.

Yuk.

I am able to just select the last name based on the comma like so:

LEFT(LastName,(CHARINDEX(',',LastName))) AS LastNameOnly

However, I am having trouble pulling out the first name. Hell, at this point, I'd be fine with it if first name contained any possible Middle Int. I'd be fine if FirstName was "John,Q". I can clean that up in a second step.

I'd be grateful if someone could help just getting the "First Name" out of the string. I've tried various methods of SUBSTRING, LEN, and what not. Just can't seem to connect the dots....

Thanks
Andrew Kernodle
Andrew Kernodle
SSC Eights!
SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)

Group: General Forum Members
Points: 802 Visits: 8135
This article should be handy:

DelimitedSplit8K

Create the DelimitedSplit8K function as detailed in the article, and CROSS APPLY it to your comma-delimited data, like so:


SELECT * FROM YourTable
CROSS APPLY YourDatabase.YourSchema.DelimitedSplit8K(YourTable.Lastname,',')



Replace the "Your" bits with your actual tables. This will show you how the original string, and how it will be split out based on the delimiter (in this case, the comma at the end of the DelimitedSplit8K call). From there, you'll need to update each part of the name with the split-out entries you end up with from using DelimitedSplit8K. This can be clarified further as needed, but it should provide a good starting point.

- :-D
RedBirdOBX
RedBirdOBX
SSC-Enthusiastic
SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)

Group: General Forum Members
Points: 154 Visits: 243
This seems to mostly work:

RIGHT(LastName,(LEN(LastName))-CHARINDEX(',',LastName)) As FirstNameOnly

I needed to use Right Trim but I didn't know how many positions to trim to. So, I did this:

Right(LastName, C)

A = Length of whole string
B = Position of Comma
C = A-B (Remaining chars)
SrcName
SrcName
SSC-Enthusiastic
SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)SSC-Enthusiastic (178 reputation)

Group: General Forum Members
Points: 178 Visits: 394
try

select

substring( lastname, charindex(',', lastName )+1,
(charindex (',', lastName, charindex(',', lastName )+1 )-
charindex(',', lastName ))-1
)
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7515 Visits: 6431
My advice is plan for the worst and use a pattern split function like the one you'll find in the 4th link in my signature.


WITH SampleData (Name) AS
(
SELECT 'Smith,John,Q'
UNION ALL SELECT 'Fedders-Smith,John,Q'
UNION ALL SELECT 'Smith, John Q'
UNION ALL SELECT 'Smith,John Quincy'
UNION ALL SELECT ' Smith,John Quincy'
)
SELECT Name
,LastName=MAX(CASE ItemNumber WHEN 1 THEN Item END)
,FirstName=MAX(CASE ItemNumber WHEN 3 THEN Item END)
,LastName=MAX(LEFT(CASE ItemNumber WHEN 5 THEN Item END, 1))
FROM
(
SELECT Name, ItemNumber, Item
FROM SampleData a
CROSS APPLY dbo.PatternSplitCM(LTRIM(Name), '[\-a-zA-Z]') b
WHERE [Matched]=1
) a
GROUP BY Name;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search