locked
MSSQL 2008 Precision Problem RRS feed

  • Question

  • Hello everyone,

    I have a problem about precision range in MSSQL 2008. I am trying to transfer data from Oracle db to MSSQL db. One column in Oracle db has a precision larger than 38, which is '76.43448990049567164100213185805651059565'. Therefore, I give an execution error like;

    Caused By: weblogic.jdbc.sqlserverbase.ddc: [FMWGEN][SQLServer JDBC Driver]The number, 76.43448990049567164100213185805651059565, has a precision larger than allowed by the SQL Server.

    What can I do at this point? Please help me

    Thank You

    • Moved by Kalman Toth Wednesday, January 22, 2014 9:37 AM Not db design
    Wednesday, January 22, 2014 7:54 AM

Answers

  • I have been posting answers to this question But its not getting posted - donno why. Here goes..

    Dilek,

    Do you really need that many decimal places? try limiting it down if possible. BEcause, SQL Server allows a max of precision value of 38 only in case of decimal/numeric. So you have the following alternatives:

    1. Reduce the number of decimal places and push it into SQL Server column having a datatype say, numeric(38,36)
    2. Split the value into two columns one for the absolute part having int type and another for decimal which can either have numeric(38,38) or an int which is to be converted to decimal during usage.
    3. Store as varchar type - but this would make it difficult to be used for calculation (Beware, even when you convert a 40 digit precision value from varchar to numeric you'll get the same error). So if it just for projecting the data (just for select) varchar should do fine.
    --method 1
    declare @tab table ( num numeric(38,36))
    insert @tab select 76.434489900495671641002131858056510595--65
    select * from @tab
    --method 2
    declare @tab table ( num int,dec numeric(38,38))
    insert @tab select 76,0.43448990049567164100213185805651059565
    select * from @tab
    select cast(num as varchar)+substring(cast(dec as varchar(100)),2,len(cast(dec as varchar(100)))),* from @tab
    select num+dec,* from @tab --decimal places get reduced beware..
    
    --method 3
    declare @tab table ( num varchar(100))
    insert @tab select 76.434489900495671641002131858056510595--65 -- ignoring last two digits
    insert @tab select '76.43448990049567164100213185805651059565' -- as varchar
    select cast(num as decimal(38,36)) from @tab --produces result for first one and error for second instance
    
    --Just normal 
    select 76.434489900495671641002131858056510595 --works
    select 76.43448990049567164100213185805651059565 -- doesnt work


    Thanks,
    Jay
    <If the post was helpful mark as 'Helpful' and if the post answered your query, mark as 'Answered'>


    • Edited by Jayakumaur (JK) Wednesday, January 22, 2014 9:51 AM typo
    • Proposed as answer by Mike Yin Thursday, January 23, 2014 10:01 AM
    • Marked as answer by Mike Yin Sunday, February 2, 2014 2:09 PM
    Wednesday, January 22, 2014 9:51 AM

All replies

  • Possibilities: convert it to less precision on ORACLE, transfer it as a string, or use SSIS.


    Kalman Toth Database & OLAP Architect SELECT Query Video Tutorial 4 Hours
    New Book / Kindle: Exam 70-461 Bootcamp: Querying Microsoft SQL Server 2012


    Wednesday, January 22, 2014 9:37 AM
  • I have been posting answers to this question But its not getting posted - donno why. Here goes..

    Dilek,

    Do you really need that many decimal places? try limiting it down if possible. BEcause, SQL Server allows a max of precision value of 38 only in case of decimal/numeric. So you have the following alternatives:

    1. Reduce the number of decimal places and push it into SQL Server column having a datatype say, numeric(38,36)
    2. Split the value into two columns one for the absolute part having int type and another for decimal which can either have numeric(38,38) or an int which is to be converted to decimal during usage.
    3. Store as varchar type - but this would make it difficult to be used for calculation (Beware, even when you convert a 40 digit precision value from varchar to numeric you'll get the same error). So if it just for projecting the data (just for select) varchar should do fine.
    --method 1
    declare @tab table ( num numeric(38,36))
    insert @tab select 76.434489900495671641002131858056510595--65
    select * from @tab
    --method 2
    declare @tab table ( num int,dec numeric(38,38))
    insert @tab select 76,0.43448990049567164100213185805651059565
    select * from @tab
    select cast(num as varchar)+substring(cast(dec as varchar(100)),2,len(cast(dec as varchar(100)))),* from @tab
    select num+dec,* from @tab --decimal places get reduced beware..
    
    --method 3
    declare @tab table ( num varchar(100))
    insert @tab select 76.434489900495671641002131858056510595--65 -- ignoring last two digits
    insert @tab select '76.43448990049567164100213185805651059565' -- as varchar
    select cast(num as decimal(38,36)) from @tab --produces result for first one and error for second instance
    
    --Just normal 
    select 76.434489900495671641002131858056510595 --works
    select 76.43448990049567164100213185805651059565 -- doesnt work


    Thanks,
    Jay
    <If the post was helpful mark as 'Helpful' and if the post answered your query, mark as 'Answered'>


    • Edited by Jayakumaur (JK) Wednesday, January 22, 2014 9:51 AM typo
    • Proposed as answer by Mike Yin Thursday, January 23, 2014 10:01 AM
    • Marked as answer by Mike Yin Sunday, February 2, 2014 2:09 PM
    Wednesday, January 22, 2014 9:51 AM
  • Thank you everyone. The problem solved :)

    Thursday, January 23, 2014 11:38 AM