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 12:27 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 6:58 AM
Points: 11, Visits: 56
I have a stored procedure which is supposed to check if a part of a datatype text field (Textdescription) has an already existing projectnumber. However the field Textdescription can also have normal text in it (thus not starting with 'Int.nr.TXT:'). Normally I would expect that because the where clause is evaluated before the select that system will only try to retrieve those records I specify using my where. However it now fails because of error: Cannot convert varchar to int.

So if my data is:

ProjectID Textfield
26 normal text in this field
26 special text in this field
26 Int.nr.TXT: 69000

System will give error: Cannot convert varchar 'n this fie' to int'. When I expect it only to retrieve those records starting with 'Int.nr.TXT'. Why does SQL still try to evaluate those other lines. I now solved it by casting the TTT_ID field also as varchar. But what is the cause? My code is:
UPDATE tblInvoicesProject
SET TTT_Factureren = 0,
TTT_FactuurStatus = 0,
TTT_FactuurNummer = 0
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:'))
Post #1479293
Posted Wednesday, July 31, 2013 2:08 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
I suspect that the cause of the problem is that you have a row in the data where TextDescription begins with 'Int.nr.TXT:' but there is no valid integer after.

This is a perfect time to use one of the new functions in SQL 2012: TRY_CAST()

TRY_CAST will return null if there was a problem with the cast instead of generating an error.

Your code could then be rewritten as:

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

Note the use of isnull to convert any failed casts from null to -1. I assume that -1 is not a valid project number.

If you have a null value in NOT IN () the results will probably not be what you expect.
Post #1479330
Posted Wednesday, July 31, 2013 2:18 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 6:58 AM
Points: 11, Visits: 56
Hi, Thank you for your response. However the goal is to only retrieve those lines starting with Int.nr.TXT:. I checked the data, all lines have a valid integer after the :. However I still do not get why, despite the where clause, SQL is trying to fetch and evaluate all rows, also those not starting with the Int.nr.TXT..
Post #1479339
Posted Wednesday, July 31, 2013 4:09 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
marc.eilander 13301 (7/31/2013)
Hi, Thank you for your response. However the goal is to only retrieve those lines starting with Int.nr.TXT:. I checked the data, all lines have a valid integer after the :. However I still do not get why, despite the where clause, SQL is trying to fetch and evaluate all rows, also those not starting with the Int.nr.TXT..


I think Stefan could be right. Try this test harness, then try query 2 on your data:

DROP TABLE #frstx
CREATE TABLE #frstx (ProjectID INT, TextDescription text)
INSERT INTO #frstx (ProjectID, TextDescription)
SELECT 26, 'normal text in this field' UNION ALL
SELECT 26, 'special text in this field' UNION ALL
SELECT 26, 'Int.nr.TXT: 69000'

-- original subquery
SELECT SUBSTRING(CAST(X.TextDescription AS VARCHAR(100)),13,10)
FROM #frstx X
WHERE (LEFT(CAST(X.TextDescription AS VARCHAR(100)), 11) = 'Int.nr.TXT:')

-- fixed for deferred expression evaluation
SELECT b.TTT_ID, X.TextDescription
FROM #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 #1479374
Posted Wednesday, July 31, 2013 5:11 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 6:58 AM
Points: 11, Visits: 56
Hi,

I followed your instructions. The results are:

Original subquery gives: 69000

Proposed query containing cross apply: 69000, Int.nr.TXT: 69000

So the original query works fine as long at is not part as a nested query for the rest of the stored procedure.
Post #1479398
Posted Wednesday, July 31, 2013 5:13 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
Have you tried both subqueries against your actual data, Marc?

“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 #1479400
Posted Wednesday, July 31, 2013 5:20 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 6:58 AM
Points: 11, Visits: 56
Sorry, bout that. I checked it now against the actual data. The orignal query only gave back valid data (only numbers). The new proposed query gave the same by first displaying the number and secondly displaying the prefix text and then the same number.
Post #1479402
Posted Wednesday, July 31, 2013 5:21 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
How many rows are returned?


“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 #1479403
Posted Wednesday, July 31, 2013 5:23 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 6:58 AM
Points: 11, Visits: 56
Both (the orignal query and the new proposed query) gave 57 rows.
Post #1479408
Posted Wednesday, July 31, 2013 5:29 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
marc.eilander 13301 (7/31/2013)
Hi, Thank you for your response. However the goal is to only retrieve those lines starting with Int.nr.TXT:. I checked the data, all lines have a valid integer after the :. However I still do not get why, despite the where clause, SQL is trying to fetch and evaluate all rows, also those not starting with the Int.nr.TXT..


The query optimizer is free to evaluate expressions and predicates in any order to get maximum performance.

It seems that for some reason the generated execution plan results in the scalar expression being evaluated before the WHERE predicate.

If you really want to know exactly what is happening, you can post an estimated query plan of your original query as an .sqlplan file (right click an execution plan and select Save Execution Plan as ...)

Post #1479411
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse