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


How to get a row number which is failing during conversion


How to get a row number which is failing during conversion

Author
Message
SqlSavvy
SqlSavvy
SSC Veteran
SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)

Group: General Forum Members
Points: 209 Visits: 300
I have about 20000 records in the SELECT clause and one of them is failing during conversion spitting out the following error message. "Arithmetic overflow error converting varchar to data type numeric.
" Is there a way to find out which row is failing?
steveb.
steveb.
SSCarpal Tunnel
SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)

Group: General Forum Members
Points: 4442 Visits: 7195
There will probably be a row that has a character that cannot be converted to integer.

try using this code to find the offending row(s)


SELECT * FROM YourTable
WHERE ISNUMERIC(YourColumn)=0


SqlSavvy
SqlSavvy
SSC Veteran
SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)

Group: General Forum Members
Points: 209 Visits: 300
Thanks for the reponse.

But that is not going to work because I am only selecting the records where ISNUMERIC(mycloumn) = 1.
Christopher Stobbs
Christopher Stobbs
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2474 Visits: 2233
Steve, cause it's an overflow I recon it's not that there is char

Also be careful because
This will return a 1 for ISNUMERIC but it's not convertible: '10,0'.


What I normally do is run a top until I find a subset of data that contains my bad value and then I go from there.
What data type are you converting to?

----------------------------------------------
Try to learn something about everything and everything about something. - Thomas Henry Huxley

w00t
Posting Best Practices
Numbers / Tally Tables

SQL-4-Life
Jack Corbett
  Jack Corbett
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18818 Visits: 14900
Check out the BOL entry for IsNumeric. "+", "-", ".", and currency symbols are all considered Numeric. Change your where clause to:


Where
Column NOT LIKE '%[^0-9]%'



This says only allow numbers ignoring all other characters. If you want to allow decimals and negatives you can add the necessary characters to the mask.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
SqlSavvy
SqlSavvy
SSC Veteran
SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)

Group: General Forum Members
Points: 209 Visits: 300
Converting to deciman(12,7)
steveb.
steveb.
SSCarpal Tunnel
SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)

Group: General Forum Members
Points: 4442 Visits: 7195
Okay sorry i mis-read the question..

It seems like the value is too big to fit into a numeric column
Christopher Stobbs
Christopher Stobbs
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2474 Visits: 2233
Also your select statement will normally return a number of rows before it actually falls over so you could use that as a point in the DB to start looking for bad data

e.g


DECLARE @TMP TABLE
(COl1 VARCHAR(100))
INSERT INTO @tmp
SELECT '1' UNION ALL
SELECT '1111111111111111111111'

SELECT CAST(col1 as decimal(12,7))
FROM @tmp



This fails but it also return one row, so I know that it's after the first row etc...

----------------------------------------------
Try to learn something about everything and everything about something. - Thomas Henry Huxley

w00t
Posting Best Practices
Numbers / Tally Tables

SQL-4-Life
Christopher Stobbs
Christopher Stobbs
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2474 Visits: 2233
The only other thing I can think of it to return all rows that have a Len(Col) greater than what your decimal can hold and look at those

----------------------------------------------
Try to learn something about everything and everything about something. - Thomas Henry Huxley

w00t
Posting Best Practices
Numbers / Tally Tables

SQL-4-Life
Christopher Stobbs
Christopher Stobbs
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2474 Visits: 2233
Ok assuming all your values are numeric then try this:
in the where clause

CHARINDEX('.',col1) > 6
OR
(CHARINDEX('.',col1) = 0 AND LEN(col1) > 5)



Here is my example for returning values that would overflow.


DECLARE @TMP TABLE
(COl1 VARCHAR(100))
INSERT INTO @tmp
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '1' UNION ALL
SELECT '92345.1234567' UNION ALL
SELECT '12345.12345671' UNION ALL
SELECT '123456.1234567' UNION ALL
SELECT '111111111111111111111111111111' UNION ALL
SELECT '1234567890'

SELECT
--CAST(col1 as decimal(12,7))
col1
FROM @tmp
WHERE
CHARINDEX('.',col1) > 6
OR
(CHARINDEX('.',col1) = 0 AND LEN(col1) > 5)



----------------------------------------------
Try to learn something about everything and everything about something. - Thomas Henry Huxley

w00t
Posting Best Practices
Numbers / Tally Tables

SQL-4-Life
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