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

Why doesn't the substring work? Expand / Collapse
Author
Message
Posted Wednesday, July 31, 2013 5:29 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Friday, September 12, 2014 9:43 AM
Points: 7,284, Visits: 13,824
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
Post #1479412
Posted Wednesday, July 31, 2013 5:41 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, September 12, 2014 1:30 AM
Points: 7, Visits: 30
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.
Post #1479415
Posted Wednesday, July 31, 2013 6:09 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, September 10, 2014 5:46 AM
Points: 316, Visits: 910
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
Post #1479428
Posted Wednesday, July 31, 2013 6:20 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Friday, September 12, 2014 9:43 AM
Points: 7,284, Visits: 13,824
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
Post #1479431
Posted Wednesday, July 31, 2013 6:57 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, September 12, 2014 1:30 AM
Points: 7, Visits: 30
Thanks again. Learned a lot.
Post #1479452
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse