Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Compare the text in a string (Re-post) Expand / Collapse
Author
Message
Posted Sunday, June 24, 2012 9:16 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, April 15, 2014 11:04 AM
Points: 24, Visits: 85

Experts,

I want to compare the text between 1st occurance of @ symbol and 1st occurance of any special character with 2nd occurance of @ symbol and next occurance of any special character. If both are not same, I would consider it as bad data.

Example:
I have employee email data in a column. My concern is only the domain part of emails.

Employee ID Email
------------ ----------
1 <mmooney@gmail.com>;"mmoney@gmail.com"
2 <chrisgardener@yahoo.com>)']chrisgardener@comcast.net)]
3 "natan@hotmail.com':>"natan@hotmail.com?'
4 "jennifer@walmart.com}';jennifer@fedex.com

I want to identify the 1st record and 3rd record as good data (because both domains are same); and 2nd record and 4th record as exceptions (because both domains are different)

What would be the best way to identify good ones and exceptions? Thanks in advance!
Post #1320423
Posted Sunday, June 24, 2012 11:48 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 2:24 AM
Points: 3,591, Visits: 5,100
This is not guaranteed to work in all cases (e.g., where @ may appear outside of an email string) but using Jeff Moden's DelimitedSplit8K string splitter, you can try something like this:

DECLARE @t TABLE (EmployeeID INT, Email VARCHAR(200))

INSERT INTO @t
SELECT 1, '<mmooney@gmail.com>;"mmoney@gmail.com"'
UNION ALL SELECT 2, '<chrisgardener@yahoo.com>)'']chrisgardener@comcast.net)]'
UNION ALL SELECT 3, '"natan@hotmail.com'':>"natan@hotmail.com?'''
UNION ALL SELECT 4, '"jennifer@walmart.com}'';jennifer@fedex.com'

SELECT EmployeeID, Email
FROM (
SELECT EmployeeID, Email, ItemNumber
,df=CASE WHEN PATINDEX('%[^0-9A-Za-z@.]%', Item) = 0
THEN Item
ELSE SUBSTRING(Item, 1, PATINDEX('%[^0-9A-Za-z@.]%', Item) - 1) END
FROM @t
CROSS APPLY dbo.DelimitedSplit8K(Email, '@') ds
WHERE CHARINDEX('.', Item) <> 0) x
GROUP BY EmployeeID, Email
HAVING MAX(df) = MIN(df)


The referenced string splitter can be found here: http://www.sqlservercentral.com/articles/Tally+Table/72993/



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!
Post #1320440
Posted Monday, June 25, 2012 9:37 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, April 17, 2014 9:33 AM
Points: 6,754, Visits: 12,854
This works quite nicely too:

SELECT 
EmployeeID,
Email,
DomainLHS = SUBSTRING(Email, x.PosStart,x.PosEnd-x.PosStart),
DomainRHS = SUBSTRING(Email, y.PosStart,y.PosEnd-y.PosStart)
FROM @t
CROSS APPLY (
SELECT PosStart = 1+CHARINDEX('@',EMAIL,1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,1)),0)
) x
CROSS APPLY (
SELECT PosStart = NULLIF(1+CHARINDEX('@',EMAIL,x.PosEnd),1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,x.PosEnd)),0)
) y



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Post #1320704
Posted Monday, June 25, 2012 3:18 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, April 15, 2014 11:04 AM
Points: 24, Visits: 85
Dwain, ChrisM@Work -

Both of your scripts are working great for my set of documents. Thanks much!
Post #1320905
Posted Monday, June 25, 2012 5:33 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 2:24 AM
Points: 3,591, Visits: 5,100
dwain.c (6/24/2012)
This is not guaranteed to work in all cases (e.g., where @ may appear outside of an email string) but using Jeff Moden's DelimitedSplit8K string splitter, you can try something like this:

DECLARE @t TABLE (EmployeeID INT, Email VARCHAR(200))

INSERT INTO @t
SELECT 1, '<mmooney@gmail.com>;"mmoney@gmail.com"'
UNION ALL SELECT 2, '<chrisgardener@yahoo.com>)'']chrisgardener@comcast.net)]'
UNION ALL SELECT 3, '"natan@hotmail.com'':>"natan@hotmail.com?'''
UNION ALL SELECT 4, '"jennifer@walmart.com}'';jennifer@fedex.com'

SELECT EmployeeID, Email
FROM (
SELECT EmployeeID, Email, ItemNumber
,df=CASE WHEN PATINDEX('%[^0-9A-Za-z@.]%', Item) = 0
THEN Item
ELSE SUBSTRING(Item, 1, PATINDEX('%[^0-9A-Za-z@.]%', Item) - 1) END
FROM @t
CROSS APPLY dbo.DelimitedSplit8K(Email, '@') ds
WHERE CHARINDEX('.', Item) <> 0) x
GROUP BY EmployeeID, Email
HAVING MAX(df) = MIN(df)


The referenced string splitter can be found here: http://www.sqlservercentral.com/articles/Tally+Table/72993/


Note that mine won't work in the case where a period (.) appears in the left part of the email name. If you were to provide additional test data, I think I could work around that. The original test data you gave us was pretty messy and I was afraid the real data would be even worse.



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!
Post #1320945
Posted Monday, June 25, 2012 7:42 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
ChrisM@Work (6/25/2012)
This works quite nicely too:

SELECT 
EmployeeID,
Email,
DomainLHS = SUBSTRING(Email, x.PosStart,x.PosEnd-x.PosStart),
DomainRHS = SUBSTRING(Email, y.PosStart,y.PosEnd-y.PosStart)
FROM @t
CROSS APPLY (
SELECT PosStart = 1+CHARINDEX('@',EMAIL,1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,1)),0)
) x
CROSS APPLY (
SELECT PosStart = NULLIF(1+CHARINDEX('@',EMAIL,x.PosEnd),1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,x.PosEnd)),0)
) y



Absolutely awesome, Chris. "Cascading Cross Applys" (cCA for short! ). Looks like it might beat the tar out of cascading CTE's of a similar nature. To be honest, I didn't know such a thing was possible because I didn't even consider that one CA might be able to use the output of another. This crazy Monday has turned into something good after all!

You should write a "Spackle" article on it, Chris.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1320965
Posted Monday, June 25, 2012 9:33 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, April 15, 2014 11:04 AM
Points: 24, Visits: 85
dwain.c, Completely understood. I will update here of any exceptions and how I handle them. Thank you.
Post #1320988
Posted Tuesday, June 26, 2012 3:29 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, April 17, 2014 9:33 AM
Points: 6,754, Visits: 12,854
Jeff Moden (6/25/2012)
ChrisM@Work (6/25/2012)
This works quite nicely too:

SELECT 
EmployeeID,
Email,
DomainLHS = SUBSTRING(Email, x.PosStart,x.PosEnd-x.PosStart),
DomainRHS = SUBSTRING(Email, y.PosStart,y.PosEnd-y.PosStart)
FROM @t
CROSS APPLY (
SELECT PosStart = 1+CHARINDEX('@',EMAIL,1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,1)),0)
) x
CROSS APPLY (
SELECT PosStart = NULLIF(1+CHARINDEX('@',EMAIL,x.PosEnd),1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,x.PosEnd)),0)
) y



Absolutely awesome, Chris. "Cascading Cross Applys" (cCA for short! ). Looks like it might beat the tar out of cascading CTE's of a similar nature. To be honest, I didn't know such a thing was possible because I didn't even consider that one CA might be able to use the output of another. This crazy Monday has turned into something good after all!

You should write a "Spackle" article on it, Chris.


Gosh thanks Jeff!

I might have to do just that


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Post #1321106
Posted Tuesday, June 26, 2012 8:13 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
ChrisM@Work (6/26/2012)
Jeff Moden (6/25/2012)
ChrisM@Work (6/25/2012)
This works quite nicely too:

SELECT 
EmployeeID,
Email,
DomainLHS = SUBSTRING(Email, x.PosStart,x.PosEnd-x.PosStart),
DomainRHS = SUBSTRING(Email, y.PosStart,y.PosEnd-y.PosStart)
FROM @t
CROSS APPLY (
SELECT PosStart = 1+CHARINDEX('@',EMAIL,1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,1)),0)
) x
CROSS APPLY (
SELECT PosStart = NULLIF(1+CHARINDEX('@',EMAIL,x.PosEnd),1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,x.PosEnd)),0)
) y



Absolutely awesome, Chris. "Cascading Cross Applys" (cCA for short! ). Looks like it might beat the tar out of cascading CTE's of a similar nature. To be honest, I didn't know such a thing was possible because I didn't even consider that one CA might be able to use the output of another. This crazy Monday has turned into something good after all!

You should write a "Spackle" article on it, Chris.


Gosh thanks Jeff!

I might have to do just that


If you do that, I'd be honored to review it for you (Word 97-2003 if you don't mind) and then show you how to submit it through the "Write for us" link.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1321261
Posted Wednesday, June 27, 2012 6:04 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, April 17, 2014 9:33 AM
Points: 6,754, Visits: 12,854
Jeff Moden (6/26/2012)
ChrisM@Work (6/26/2012)
Jeff Moden (6/25/2012)
ChrisM@Work (6/25/2012)
This works quite nicely too:

SELECT 
EmployeeID,
Email,
DomainLHS = SUBSTRING(Email, x.PosStart,x.PosEnd-x.PosStart),
DomainRHS = SUBSTRING(Email, y.PosStart,y.PosEnd-y.PosStart)
FROM @t
CROSS APPLY (
SELECT PosStart = 1+CHARINDEX('@',EMAIL,1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,1)),0)
) x
CROSS APPLY (
SELECT PosStart = NULLIF(1+CHARINDEX('@',EMAIL,x.PosEnd),1),
PosEnd = NULLIF(CHARINDEX('.',EMAIL,CHARINDEX('@',EMAIL,x.PosEnd)),0)
) y



Absolutely awesome, Chris. "Cascading Cross Applys" (cCA for short! ). Looks like it might beat the tar out of cascading CTE's of a similar nature. To be honest, I didn't know such a thing was possible because I didn't even consider that one CA might be able to use the output of another. This crazy Monday has turned into something good after all!

You should write a "Spackle" article on it, Chris.


Gosh thanks Jeff!

I might have to do just that


If you do that, I'd be honored to review it for you (Word 97-2003 if you don't mind) and then show you how to submit it through the "Write for us" link.


I'm speechless Jeff, that's very kind, thank you.
This technique isn't exactly new though. I can remember the first time I posted a solution using it, possibly as long as a couple of years ago. However, if you feel it's worthwhile (a few recent posts suggests it might be), then I'll go for it.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Post #1321806
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse