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


Why doesn't the substring work?


Why doesn't the substring work?

Author
Message
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17246 Visits: 19557
Ok - try these:

SELECT 
TTT_Factureren = 0,
TTT_FactuurStatus = 0,
TTT_FactuurNummer = 0
FROM tblInvoicesProject
WHERE TTT_ProjectID = 26
AND TTT_FactuurStatus = 1
AND TTT_ID NOT IN (
SELECT SUBSTRING(CAST(X.TextDescription AS VARCHAR(100)),13,10)
FROM [500].dbo.frstx X
WHERE (LEFT(CAST(X.TextDescription AS VARCHAR(100)), 11) = 'Int.nr.TXT:')
)

SELECT
TTT_Factureren = 0,
TTT_FactuurStatus = 0,
TTT_FactuurNummer = 0
FROM tblInvoicesProject
WHERE TTT_ProjectID = 26
AND TTT_FactuurStatus = 1
AND TTT_ID NOT IN (
SELECT b.TTT_ID
FROM [500].dbo.frstx X
CROSS APPLY (SELECT ChosenRow = CASE WHEN X.TextDescription LIKE 'Int.nr.TXT:%' THEN 1 ELSE 0 END) a
CROSS APPLY (
SELECT TTT_ID = CASE WHEN ChosenRow = 1 THEN CAST(SUBSTRING(CAST(X.TextDescription AS VARCHAR(100)),13,10) AS INT) END) b
WHERE ChosenRow = 1
)



“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
marc.eilander 13301
marc.eilander 13301
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 70
Thank you both very much. Since this issue occurs after migrating from sql 2000 to sql 2008 I suspect the performance issues which were adressed by Microsoft in SQL 2008 probably changed the execution plan. Unfortunately I have no data on SQL 2000 to compare this. Thanks again for getting more insight in this.
Stefan_G
Stefan_G
Mr or Mrs. 500
Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)Mr or Mrs. 500 (525 reputation)

Group: General Forum Members
Points: 525 Visits: 961
Since you are on SQL2008, you can forget about TRY_CAST since this is a SQL2012 feature only.

On SQL2008 you could use a CASE expression to guard the expression evaluation to avoid this issue.

Like this:
UPDATE   #t2
SET TTT_Factureren = 0,
TTT_FactuurStatus = 0,
TTT_FactuurNummer = 0
WHERE TTT_ProjectID = 26
AND TTT_FactuurStatus = 1
AND TTT_ID NOT IN(
SELECT
CASE WHEN X.TextDescription LIKE 'Int.nr.TXT:%'
THEN CAST(SUBSTRING(CAST(X.TextDescription AS VARCHAR(100)),13,10) as int)
ELSE -1
END
FROM #t1 X
WHERE X.TextDescription LIKE 'Int.nr.TXT:%'
)



Note the use of LIKE which gives much better performance than SUBSTRING in the predicate
This method is also more efficient than casting TTT_ID to a varchar since it is much faster to compare integers than strings.

Good luck
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17246 Visits: 19557
Stefan_G (7/31/2013)
Since you are on SQL2008, you can forget about TRY_CAST since this is a SQL2012 feature only.

On SQL2008 you could use a CASE expression to guard the expression evaluation to avoid this issue.

Like this:
UPDATE   #t2
SET TTT_Factureren = 0,
TTT_FactuurStatus = 0,
TTT_FactuurNummer = 0
WHERE TTT_ProjectID = 26
AND TTT_FactuurStatus = 1
AND TTT_ID NOT IN(
SELECT
CASE WHEN X.TextDescription LIKE 'Int.nr.TXT:%'
THEN CAST(SUBSTRING(CAST(X.TextDescription AS VARCHAR(100)),13,10) as int)
ELSE -1
END
FROM #t1 X
WHERE X.TextDescription LIKE 'Int.nr.TXT:%'
)



Note the use of LIKE which gives much better performance than SUBSTRING in the predicate
This method is also more efficient than casting TTT_ID to a varchar since it is much faster to compare integers than strings.

Good luck


That's pretty much how I saw it too, Stefan ;-)

“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
marc.eilander 13301
marc.eilander 13301
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 70
Thanks again. Learned a lot.
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