September 30, 2013 at 1:18 am
I am trying to capture an email address from the below message..whats the best possible way to do it ..
DECLARE @test-2 VARCHAR(500)
SET @test-2 = 'my email is Test@email.com.au how do i capture just the email'
This is what I have tried but couldn't get to finish it where I can capture the whole email address
SELECT SUBSTRING(@test,CHARINDEX('@',@test),CHARINDEX(' ',@test,CHARINDEX('@',@test))-CHARINDEX('@',@test))
Thanks in Advance
Thanks,
Chinna
Its the Journey which gives you Happiness not the Destination-- Dan Millman
September 30, 2013 at 1:22 am
Chinna
You need to REVERSE the string and then look for the first space after the "@".
John
September 30, 2013 at 1:53 am
Hi,
Use this script
DECLARE @test-2 VARCHAR(500)
SET @test-2 = 'my email is Test@email.com.au how do i capture just the email'
SELECT REVERSE(SUBSTRING(REVERSE(@test),CHARINDEX('@',REVERSE(@test))+1,CHARINDEX(' ',REVERSE(@test),CHARINDEX('@',REVERSE(@test)))-CHARINDEX('@',REVERSE(@test))))
+SUBSTRING(@test,CHARINDEX('@',@test),CHARINDEX(' ',@test,CHARINDEX('@',@test))-CHARINDEX('@',@test))
September 30, 2013 at 6:56 am
-- solution
;WITH SampleData AS (
SELECT test = 'my email is Test@email.com.au how do i capture just the email' UNION ALL
SELECT 'No email address in this string'
)
SELECT test, x3.p3
FROM SampleData
CROSS APPLY (SELECT p1 = NULLIF(CHARINDEX('@',test,1),0)) x1
CROSS APPLY (SELECT p2 = SUBSTRING(test,(2+p1-CHARINDEX(' ',REVERSE(LEFT(test, x1.p1)))),8000)) x2
CROSS APPLY (SELECT p3 = LEFT(p2,CHARINDEX(' ',p2,1)-1)) x3;
-- workings
;WITH SampleData AS (
SELECT test = 'my email is Test@email.com.au how do i capture just the email' UNION ALL
SELECT 'No email address in this string'
)
SELECT *
FROM SampleData
CROSS APPLY (SELECT p1 = NULLIF(CHARINDEX('@',test,1),0)) x1
CROSS APPLY (SELECT p2 = LEFT(test, x1.p1)) x2
CROSS APPLY (SELECT p3 = REVERSE(p2)) x3
CROSS APPLY (SELECT p4 = CHARINDEX(' ',p3)) x4
CROSS APPLY (SELECT p5 = 2+p1-p4) x5
CROSS APPLY (SELECT p6 = SUBSTRING(test,p5,8000)) x6
CROSS APPLY (SELECT p7 = LEFT(p6,CHARINDEX(' ',p6,1)-1)) x7;
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
September 30, 2013 at 9:44 am
Just another possible solution.
SELECT *
FROM DelimitedSplit8K(@test, ' ') x
WHERE CHARINDEX( '@', x.Item) > 0
For the code of DelimitedSplit8K please read the following article:
October 1, 2013 at 6:50 pm
To add onto Luis's suggestion:
WITH SampleData AS (
SELECT test = 'my email is Test@email.com.au how do i capture just the email' UNION ALL
SELECT 'Some invalid@email addresses can also be removed like this' UNION ALL
SELECT 'Some invalid @email addresses can also be removed like this' UNION ALL
SELECT 'Some invalid email@. addresses can also be removed like this' UNION ALL
SELECT 'Some invalid email@@address.can can also be removed like this' UNION ALL
SELECT 'No email address in this string'
)
SELECT test, item
FROM SampleData a
CROSS APPLY dbo.DelimitedSplit8K(test, ' ') b
WHERE CHARINDEX('@', item) < CHARINDEX('.', item) AND CHARINDEX('@', item) > 1 AND
CHARINDEX('.', item) < LEN(item) AND LEN(item) - 1 = LEN(REPLACE(item, '@', ''));
Etc.
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
October 2, 2013 at 9:18 pm
Thanks a lot guys...All of the responses were helpful .
Thanks,
Chinna
Its the Journey which gives you Happiness not the Destination-- Dan Millman
October 3, 2013 at 8:01 am
Luis Cazares (9/30/2013)
Just another possible solution.
SELECT *
FROM DelimitedSplit8K(@test, ' ') x
WHERE CHARINDEX( '@', x.Item) > 0
For the code of DelimitedSplit8K please read the following article:
๐
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply