Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


I need help with my query. I found part of this, but doesn't work. Please help.


I need help with my query. I found part of this, but doesn't work. Please help.

Author
Message
tbmabry
tbmabry
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 28
I need to get the emails from the n.Note field, which is a nVarchar(max) column.


I have the following, but I get an error saying "Invalid length parameter passed to the LEFT or SUBSTRING Function.


Select s.FirstName, s.LastName, c.CustomerNo, h.OppNo, n.Note,
SUBSTRING(SUBSTRING(n.Note,1,CHARINDEX(' ',n.Note,CHARINDEX('@', n.Note))-1),CHARINDEX('@', n.Note) - CHARINDEX(' ',REVERSE(SUBSTRING(n.Note,1,CHARINDEX('@', n.Note)-1))) + 1, 255)
from SalesLink_SalesRep s,
SalesLink_Prospect_SalesRepCustomerXrf c,
Opportunity_Header h,
Opportunity_Note n
where c.SalesRepId = s.SalesRepId
and c.CustomerNo = h.CustomerNo
and h.OppNo = n.OppNo
and s.SalesRepId in (238, 328)
and n.Note like '%@%'
order by CustomerNo;
SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21071 Visits: 18259
It looks like you have some data that does not meet the requirements (an invalid email address or the @ symbol is present without an email address).

Can you provide sample data for this field?



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

baabhu
baabhu
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1417 Visits: 1215
tbmabry (1/2/2013)
I need to get the emails from the n.Note field, which is a nVarchar(max) column.


I have the following, but I get an error saying "Invalid length parameter passed to the LEFT or SUBSTRING Function.


Select s.FirstName, s.LastName, c.CustomerNo, h.OppNo, n.Note,
SUBSTRING(SUBSTRING(n.Note,1,CHARINDEX(' ',n.Note,CHARINDEX('@', n.Note))-1),CHARINDEX('@', n.Note) - CHARINDEX(' ',REVERSE(SUBSTRING(n.Note,1,CHARINDEX('@', n.Note)-1))) + 1, 255)
from SalesLink_SalesRep s,
SalesLink_Prospect_SalesRepCustomerXrf c,
Opportunity_Header h,
Opportunity_Note n
where c.SalesRepId = s.SalesRepId
and c.CustomerNo = h.CustomerNo
and h.OppNo = n.OppNo
and s.SalesRepId in (238, 328)
and n.Note like '%@%'
order by CustomerNo;


Split each of the function in a separate query and run, then you know which function is not working. Alternately filter the records by customer number till you get error batch then check the data for that batch.
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Instead of write-only code, I've always found it immensely helpful to split up complex string manipulations for readability into individual parts using cascading CROSS APPLYs like this:


;WITH Notes (Note) AS (
SELECT 'aaa abc@wondwerks.com bbb'
UNION ALL SELECT 'dwain.c@sqlservercentral.com'
UNION ALL SELECT 'dwain.c@'
UNION ALL SELECT '@sqlservercentral.com'
UNION ALL SELECT 'aaa @sqlservercentral.com'
UNION ALL SELECT '@')
SELECT email
FROM Notes
CROSS APPLY (SELECT CHARINDEX('@', Note)) a (PosOfAt)
CROSS APPLY (
SELECT SUBSTRING(Note, 1, PosOfAt - 1)
,SUBSTRING(Note, PosOfAt + 1, LEN(Note))) b(Leading, Trailing)
CROSS APPLY (
SELECT REVERSE(LEFT(REVERSE(Leading), CHARINDEX(' ', REVERSE(Leading) + ' ') - 1)) + '@' +
LEFT(Trailing, CHARINDEX(' ', Trailing + ' ') - 1)) c(email)
WHERE LEFT(email, 1) <> '@' AND RIGHT(email, 1) <> '@'




If you can apply this to your Notes field, you should be able to find only email addresses that contain text on both sides of the @.

Alternatively, you can also use a PATINDEX to isolate only the valid email addresses like this:


;WITH Notes (Note) AS (
SELECT 'aaa abc@wondwerks.com bbb'
UNION ALL SELECT 'dwain.c@sqlservercentral.com'
UNION ALL SELECT 'dwain.c@'
UNION ALL SELECT '@sqlservercentral.com'
UNION ALL SELECT 'aaa @sqlservercentral.com'
UNION ALL SELECT '@')
SELECT Note
FROM Notes
WHERE Note LIKE '%[0-9A-Za-z.][@][0-9A-Za-z.]%'




You'll probably need to add in a few characters to the left [0-9A-Za-z.], like underscore (_), etc. to include all possible valid email address characters.


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
tbmabry
tbmabry
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 28
I tried this but it didn't work. I don't know what the emails are going to be they are from all over the U.S. There are over 4000 records that I am going to be pulling from.
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
tbmabry (1/2/2013)
I tried this but it didn't work. I don't know what the emails are going to be they are from all over the U.S. There are over 4000 records that I am going to be pulling from.


Since you didn't use the Quote button, it is difficult to tell whose suggestion you tried.


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
Bhuvnesh
Bhuvnesh
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2924 Visits: 4076
tbmabry (1/2/2013)
I tried this but it didn't work. I don't know what the emails are going to be they are from all over the U.S. There are over 4000 records that I am going to be pulling from.
have you written the below code yourself
SUBSTRING(SUBSTRING(n.Note,1,CHARINDEX(' ',n.Note,CHARINDEX('@', n.Note))-1),CHARINDEX('@', n.Note) - CHARINDEX(' ',REVERSE(SUBSTRING(n.Note,1,CHARINDEX('@', n.Note)-1))) + 1, 255)


IF yes then first only select the innermost function then start overlapping the outer ones .one by one.
this can help you to trace the culprit record.
another thing , first select TOP 100 then TOP 500 and so on , then see which selection is giving error. in this way you can avoid to traverse complete 4000 records.

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Bhuvnesh (1/2/2013)
tbmabry (1/2/2013)
I tried this but it didn't work. I don't know what the emails are going to be they are from all over the U.S. There are over 4000 records that I am going to be pulling from.
have you written the below code yourself
SUBSTRING(SUBSTRING(n.Note,1,CHARINDEX(' ',n.Note,CHARINDEX('@', n.Note))-1),CHARINDEX('@', n.Note) - CHARINDEX(' ',REVERSE(SUBSTRING(n.Note,1,CHARINDEX('@', n.Note)-1))) + 1, 255)


IF yes then first only select the innermost function then start overlapping the outer ones .one by one.
this can help you to trace the culprit record.
another thing , first select TOP 100 then TOP 500 and so on , then see which selection is giving error. in this way you can avoid to traverse complete 4000 records.


http://rjlipton.wordpress.com/2012/04/04/a-lazy-approach-to-problem-solving/


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
SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21071 Visits: 18259
Tbmabry, did this post by dwain help you?

dwain.c (1/2/2013)
Instead of write-only code, I've always found it immensely helpful to split up complex string manipulations for readability into individual parts using cascading CROSS APPLYs like this:


;WITH Notes (Note) AS (
SELECT 'aaa abc@wondwerks.com bbb'
UNION ALL SELECT 'dwain.c@sqlservercentral.com'
UNION ALL SELECT 'dwain.c@'
UNION ALL SELECT '@sqlservercentral.com'
UNION ALL SELECT 'aaa @sqlservercentral.com'
UNION ALL SELECT '@')
SELECT email
FROM Notes
CROSS APPLY (SELECT CHARINDEX('@', Note)) a (PosOfAt)
CROSS APPLY (
SELECT SUBSTRING(Note, 1, PosOfAt - 1)
,SUBSTRING(Note, PosOfAt + 1, LEN(Note))) b(Leading, Trailing)
CROSS APPLY (
SELECT REVERSE(LEFT(REVERSE(Leading), CHARINDEX(' ', REVERSE(Leading) + ' ') - 1)) + '@' +
LEFT(Trailing, CHARINDEX(' ', Trailing + ' ') - 1)) c(email)
WHERE LEFT(email, 1) <> '@' AND RIGHT(email, 1) <> '@'




If you can apply this to your Notes field, you should be able to find only email addresses that contain text on both sides of the @.

Alternatively, you can also use a PATINDEX to isolate only the valid email addresses like this:


;WITH Notes (Note) AS (
SELECT 'aaa abc@wondwerks.com bbb'
UNION ALL SELECT 'dwain.c@sqlservercentral.com'
UNION ALL SELECT 'dwain.c@'
UNION ALL SELECT '@sqlservercentral.com'
UNION ALL SELECT 'aaa @sqlservercentral.com'
UNION ALL SELECT '@')
SELECT Note
FROM Notes
WHERE Note LIKE '%[0-9A-Za-z.][@][0-9A-Za-z.]%'




You'll probably need to add in a few characters to the left [0-9A-Za-z.], like underscore (_), etc. to include all possible valid email address characters.




Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

tbmabry
tbmabry
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 28
Ok, thanks. I found one of them that is making it blow up. It is that the note only has earl@dcande.com with nothing else so no space before the earl part. How do I get around this. I am using the ...


Select s.FirstName, s.LastName, c.CustomerNo, h.OppNo, n.Note,
SUBSTRING(SUBSTRING(n.Note,1,CHARINDEX(' ',n.Note,CHARINDEX('@', n.Note))-1),CHARINDEX('@', n.Note) - CHARINDEX(' ',REVERSE(SUBSTRING(n.Note,1,CHARINDEX('@', n.Note)-1))) + 1, 255)
from SalesLink_SalesRep s,
SalesLink_Prospect_SalesRepCustomerXrf c,
Opportunity_Header h,
Opportunity_Note n
where c.SalesRepId = s.SalesRepId
and c.CustomerNo = h.CustomerNo
and h.OppNo = n.OppNo
and s.SalesRepId in (238, 328)
and n.Note like '%@%'
order by CustomerNo;
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