Arithmetic overflow error converting numeric to data type numeric
Asked Answered
G

8

132

I keep getting this error message everytime I run this query:

Msg 8115, Level 16, State 8, Line 33
Arithmetic overflow error converting numeric to data type numeric.
The statement has been terminated.

But if I change the create table to (7,0), I don't get the error message.But I need my data to be displayed as a decimal. I have tried 8,3 does not work.

DECLARE @StartDate AS DATETIME
DECLARE @StartDate_y AS DATETIME
DECLARE @EndDate AS DATETIME
DECLARE @temp_y AS DATETIME

SET @temp_y = Dateadd(yy, Datediff(yy, 0, Getdate()), 0)
SET @StartDate_y = Dateadd(dd, 1 - Datepart(dw, Dateadd("ww", -2, @temp_y)),
                                      Dateadd("ww", -2, @temp_y))
SET @StartDate = Dateadd(dd, 1 - Datepart(dw, Dateadd("ww", -2, Getdate())),
                                  Dateadd("ww", -2, Getdate()))
SET @EndDate = Dateadd(dd, 6, @StartDate)

--temp table to hold all cities in list
CREATE TABLE ##temp
  (
     city VARCHAR(50)
  )

INSERT INTO ##temp
VALUES     ('ABERDEEN'),
            ('CHESAPEAKE'),
            ('Preffered-Seafood/CHICAGO'),
            ('Preffered-Redist/CHICAGO'),
            ('CLACKAMAS'),
            ('COLUMBUS'),
            ('CONKLIN'),
            ('DENVER'),
            ('FORT WORTH'),
            ('HANOVER PARK'),
            ('JACKSONVILLE'),
            ('LAKELAND'),
            ('MONTGOMERY'),
            ('PFW-NORTHEAST'),
            ('PFW-SOUTHEAST'),
            ('RIVERSIDE'),
            ('TRENTON,CANADA'),
            ('VERNON')

--temp to hold data for the cities
CREATE TABLE #temp
  (
     city            VARCHAR(50),
     ytdshipments    INT,
     ytdtotalweight  DECIMAL(7, 2) NOT NULL,
     ytdtotalcharges DECIMAL (7, 2) NOT NULL
  --YTDRevperPound decimal (7,2) not null
  )

INSERT INTO #temp
SELECT ##temp.city,
       0,
       0,
       0
FROM   ##temp

INSERT #temp
-- YTD shipments/Charges/Weight by city
SELECT city = CASE
                WHEN nameaddrmstr_1.city IN( 'ABERDEEN', 'CHESAPEAKE', 'CHICAGO'
                                             ,
                                             'CLACKAMAS',
                                             'COLUMBUS', 'CONKLIN', 'DENVER',
                                             'FORT WORTH',
                                             'HANOVER PARK', 'JACKSONVILLE',
                                             'LAKELAND'
                                             ,
                                             'MONTGOMERY'
                                                    ,
                                             'RIVERSIDE', 'TRENTON', 'VERNON' )
              THEN
                CASE
                  WHEN
              nameaddrmstr_1.city = 'CHICAGO'
              AND h.shipr = 'PREFRESVS' THEN 'Preffered-Redist/CHICAGO'
                WHEN
              nameaddrmstr_1.city = 'TRENTON'
              AND nameaddrmstr_1.city = 'CA' THEN 'TRENTON,CANADA'
                ELSE
              nameaddrmstr_1.city
                END
                ELSE 'Other'
              END,
       ytdshipments = COUNT(CONVERT(VARCHAR(10), h.dateshipped, 101)),
       ytdtotalweight =SUM(CASE
                             WHEN h.totaldimwgt > h.totalwgt THEN h.totaldimwgt
                             ELSE h.totalwgt
                           END),
       ytdtotalcharges = SUM (cs.totalestrevcharges)
--YTDRevperPound = convert(decimal(7,2),sum (cs.TotalEstRevCharges )/sum( CASE WHEN h.TotalDimWGT > > h.TotalWGT THEN h.TotalDimWGT ELSE h.TotalWGT END ))
FROM   as400.dbo.hawb AS h WITH(nolock)
       INNER JOIN as400.dbo.chargesummary AS cs
         ON h.hawbnum = cs.hawbnum
       LEFT OUTER JOIN as400.dbo.nameaddrmstr AS nameaddrmstr_1
         ON h.shipr = nameaddrmstr_1.nameaddrcode
WHERE  h.dateshipped >= '01/01/2010'
       AND h.dateshipped <= '12/19/2010'
       --WHERE H.DateShipped >= >= @StartDate_y AND H.dateshipped <= @EndDate 
       AND h.cust IN( 'DARDENREED', 'MAINEDARDE', 'MBMRIVRSDE', 'MBMCOLUMBS',
                      'MBMLAKELND', 'MBMFTWORTH', 'SYGMACOLUM', 'SYGMANETW6',
                      'MAI215', 'MBMMNTGMRY' )
GROUP  BY CASE
  WHEN nameaddrmstr_1.city IN( 'ABERDEEN', 'CHESAPEAKE', 'CHICAGO', 'CLACKAMAS',
                               'COLUMBUS', 'CONKLIN', 'DENVER', 'FORT WORTH',
                               'HANOVER PARK', 'JACKSONVILLE', 'LAKELAND',
                               'MONTGOMERY'
                                      ,
                               'RIVERSIDE', 'TRENTON', 'VERNON' ) THEN CASE
                                                                         WHEN
nameaddrmstr_1.city = 'CHICAGO'
AND h.shipr = 'PREFRESVS' THEN 'Preffered-Redist/CHICAGO'
                                                                         WHEN
nameaddrmstr_1.city = 'TRENTON'
AND nameaddrmstr_1.city = 'CA' THEN 'TRENTON,CANADA'
                                                                         ELSE
nameaddrmstr_1.city
                                                                       END
  ELSE 'Other'
END

SELECT #temp.city                 AS city,
       MAX(#temp.ytdshipments)    AS ytdshipments,
       MAX(#temp.ytdtotalweight)  AS ytdtotalweight,
       MAX(#temp.ytdtotalcharges) AS ytdtotalcharges
FROM   #temp WITH(nolock)
       LEFT OUTER JOIN ##temp
         ON ##temp.city = #temp.city
GROUP  BY #temp.city

DROP TABLE #temp

DROP TABLE ##temp  
Godroon answered 12/1, 2011 at 16:0 Comment(4)
I'm not even going to start tidying that upPerisarc
I chucked your SQL through the online formatter here. dpriver.com/pp/sqlformat.htm Could still do with a manual tidy up though.Paddy
why isn't the option of a formatter built in?Grume
Microsoft, if you're listening, the error message "Msg 8115, Level 16, State 8, Line 1 Arithmetic overflow error converting numeric to data type numeric." could be improved by indicating the original value that could not be converted. That would help a lot when loading a table of 100bn rows and trying to understand which value was offending. Adding the column number of a SELECT would be as useful again. EG. SELECT CAST(12345678910 as decimal(12,0)), CAST(12345678910 as decimal(12,2)) ...add the string: " Value: 12345678910 Column: 2" to the error message.Enhanced
R
241

My guess is that you're trying to squeeze a number greater than 99999.99 into your decimal fields. Changing it to (8,3) isn't going to do anything if it's greater than 99999.999 - you need to increase the number of digits before the decimal. You can do this by increasing the precision (which is the total number of digits before and after the decimal). You can leave the scale the same unless you need to alter how many decimal places to store. Try decimal(9,2) or decimal(10,2) or whatever.

You can test this by commenting out the insert #temp and see what numbers the select statement is giving you and see if they are bigger than your column can handle.

Retsina answered 12/1, 2011 at 16:28 Comment(4)
I wouldn't bother replying to questions from people with auto-generated accounts; they don't understand where they are and they don't come back once they've had their fix. @user572984: HELLO!? ANYONE HOME? <taps screen> Nope, didn't think so.Autarch
I had taken off the dot of decimal number, so it got bigger. Thanks!Fortepiano
Check Database field length equals in order to to DataTableAdapter that specific column's Length - Stored Procedure's specific parameter LengthFloatage
@OlaTuvesson, fortunately, although User572984 is long one and likely will never see this, as of today (Oct 8, 2020) it has been viewed Over 270K Times! So, in paying it back to UnknownUser, it's benefited as many as 270K SO users!Centuplicate
C
133

I feel I need to clarify one very important thing, for others (like my co-worker) who came across this thread and got the wrong information.

The answer given ("Try decimal(9,2) or decimal(10,2) or whatever.") is correct, but the reason ("increase the number of digits before the decimal") is wrong.

decimal(p,s) and numeric(p,s) both specify a Precision and a Scale. The "precision" is not the number of digits to the left of the decimal, but instead is the total precision of the number.

For example: decimal(2,1) covers 0.0 to 9.9, because the precision is 2 digits (00 to 99) and the scale is 1.

decimal(4,1) covers 000.0 to 999.9
decimal(4,2) covers 00.00 to 99.99
decimal(4,3) covers 0.000 to 9.999

Centuplicate answered 12/12, 2014 at 19:23 Comment(4)
By increasing the precision and leaving the scale the same, you are increasing the number of digits before the decimal. So what I said is not wrong, but I do see how it could be misunderstood. I said it that way because the OP was originally trying to fix the problem by just increasing the scale, but you are correct; it's the total precision that needs to be increased.Retsina
WOW! Thank you so much man.. This answer really helped me a lot.Weisburgh
I was still getting this error even when I used decimal(9, 2) & decimal(10, 2). But decimal(15, 2) worked for me.Rappee
Of course, your situation will vary from the OP, but it's crucial to understand why decimal(15,2) works in your situation. If you need to use 2 decimals of Scale (for example, if you are working with currency that uses 2 decimals of scale) then your only recourse is to increase the Precision. The OP was manipulating weights, which may have no fixed Scale. Scale is the number of digits after the decimal, and Precision is the total number of digits including the decimal portion. If decimal(10,2) is still resulting in Arithmetic Overflow errors, then you need to increase Precision.Centuplicate
O
4

(7,2) it means, variable will contain 5 digits before the decimal and 2 digits after decimal .if you are putting 7 digits before the decimal that is wrong.

for better understand :- https://www.sqlshack.com/understanding-sql-decimal-data-type/

Once answered 14/8, 2021 at 14:13 Comment(0)
P
3

Use TRY_CAST function in exact same way of CAST function. TRY_CAST takes a string and tries to cast it to a data type specified after the AS keyword. If the conversion fails, TRY_CAST returns a NULL instead of failing.

Pike answered 10/9, 2020 at 15:53 Comment(3)
TRY_CAST takes an expression, the value of which is cast. Not just strings as you put it.Johnniejohnny
Although that would permit the routine to complete without error, it would be at the cost of missing data. The purpose for the error is to indicate that intervention is required to prevent missing data. Your solution would work only if you truly don't care if the result is present or not.Centuplicate
@d bragg , valid point but sometimes having 99.9% of the data is better than spending a day hunting for the 1 bad data point.Isolating
L
1

If you want to reduce the size to decimal(7,2) from decimal(9,2) you will have to account for the existing data with values greater to fit into decimal(7,2). Either you will have to delete those numbers are truncate it down to fit into your new size. If there was no data for the field you are trying to update it will do it automatically without issues

Lifetime answered 3/1, 2014 at 22:3 Comment(0)
I
0

I approach these problems by trying to isolate the select statement.

Comment out fields until you can isolate which field is actually the problem.

Once you can say : Select from

you can then add Cast(field as numeric(4,6)) [tryMe]

This has the benefit of selecting N rows and then throwing the error. You can then take the cast off and see what value N+1 has.

The result is usually surprising... or you would not be reading this SO!

I had a problem today where I was calculating tax and had Numeric(7,4) The issue wound up being I had one order that owed 1000$ in tax.

Numeric(7,4) will only allow 3 digits to the left of the decimal. DOH!

Isolating answered 28/10, 2021 at 18:55 Comment(0)
S
0
(4 rows affected)
Msg 8115, Level 16, State 8, Line 3
Arithmetic overflow error converting int to data type numeric.

This error will occur when inserting data is not matching with declared decimal data type in the table.

To resolve this error, you have to modify the decimal data type limit or modify the test data.

Spume answered 2/3 at 15:51 Comment(1)
Pardon me, but I don't see anything in your answer that isn't already explained in the other answers. What am I missing? So thirteen years after the question was first posted, how does your answer enhance all the other answers?Maritzamariupol
K
-2

check your value which you want to store in integer column. I think this is greater then range of integer. if you want to store value greater then integer range. you should use bigint datatype

Kimmi answered 18/9, 2020 at 8:54 Comment(1)
The OP indicates that the column in question is Numeric, not Integer (as indicated by the error message "Arithmetic overflow error converting numeric to data type numeric."), and the top posted answer addresses this correctly. Your answer correctly identifies the problem (insufficient room to store the result) but misses the original intent of the question.Centuplicate

© 2022 - 2024 — McMap. All rights reserved.