-
Notifications
You must be signed in to change notification settings - Fork 294
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
SqlClient fails to convert decimal(38,20) to .Net decimal for values within the range of .Net's decimal type #95
Comments
I've got a debuggable reproduction but I don't really understand what the problem is even though I can see it occurring. The sql decimal requires 16 bytes to represent because that 5 spills into the last uint, and I think you're saying that even though it's 16 bytes in sql the actual value can be represented in a decimal because they use different scales. Is that right? and if so how do you convert from one representation to the other? |
I'll ask around for an authoritative layout for the decimal(38,20). |
The layout seems fine and I agree with your assertion that the value it is representing is in range of a .net decimal type, so there needs to be some sort of conversion I just don't know that isn't being done or how it would be. |
I think the problem is that the scale is excessive for that value. If you lower the scale it'll work so the value itself is fine but forcing that precision and scale makes the TDS representation use 16 bytes to represent it which hits the check that you point out fails. |
Ok, I think I know what the bug is. This
You can see the byte order like this:
outputs
So .Net is failing whenever any of most-significant bytes is non-zero. That is the correct behavior for The 16-byte integer has to be divided by 10^s to determine if it's out of bounds. IE the position of the non-zero bytes in the 16-byte integer will change depending on the scale. eg
outputs
In other words if the 4 most-significant bytes are 0s, then there can be no overflow. But if the most-significant bytes are non-zero, and the declared scale is high, and some of the least-significant bytes are zero then there is also no overflow. |
As recently announced in the .NET Blog, focus on new SqlClient features an improvements is moving to the new Microsoft.Data.SqlClient package. For this reason, we are moving this issue to the new repo at https://github.com/dotnet/SqlClient. We will still use https://github.com/dotnet/corefx to track issues on other providers like System.Data.Odbc and System.Data.OleDB, and general ADO.NET and .NET data access issues. |
This same exception occurs in .NET Framework and Core. It seems like a fairly basic bug but I'm guessing there is a good reason it hasn't been discovered yet. Priority wise, I'm going to consider this an edge case for now unless there is more information that is occurs in a more general use case. |
When mapping data from SQL Decimal(38,15) to .net decimal, this driver is throwing Conversion Overflow exception. Bug is already tracked under dotnet#95. This fix tries to alter this functionality, by rounding to nearest allowable decimal value.
When mapping data from sql Decimal(38,15) to .net decimal, this driver is throwing CoNversion overflow exception. Bug is already tracked under dotnet#95. This fix tries to alter this functionality, by rounding to nearest allowable decimal value.
@David-Engel, I have the same issue, I am trying to retrieve value: 1234567891234.56789 stored in SQL as: 1234567891234.56789000000000000, because of a column data type decimal(35,17), as you can see it does not exceed the limit of the .Net decimal type if you ignore the 0's. Can you recommend an interim solution while this is set as low priority? |
As a workaround, use an intermediate conversion to string. Either on SQL Server with a CAST or on the client like this:
|
Thank you for the reply @dbrownems, much appreciated. Note that I am using Entity Framework Core 2.1, any suggestion would be great? |
Would it be possible to remove or exclude the trailing zeros when the _value._numericInfo.scale exceed 28 in the below extract, in that way you keep your precision there is no rounding issue, and throwing the conversion overflow is more valid? if (StorageType.Decimal == _type) |
I'm hitting the same issue. We have a test which writes a random |
Same problem here. A simple entity project generated from a sql server database cannot write decimals from c# back to the database, even when they are both of same type decimal. |
Any updates on this? This issue is present since 3 years. |
It is on the to-do list this semester. |
This program
fails with
System.OverflowException: 'Conversion overflows.'
at SqlBuffer.cs line 254:
This value is well within the range of a .NET decimal, and it's a value that the SqlClient can write using a SqlParameter. So it should be converted to .NET decimal.
The byte pattern in SQL and TDS for this value is:
0x261400010000D877FB4DEE8B51699A5005000000
And it looks like SqlBuffer refuses to convert any value with a non-zero value in the last 4 bytes. But a .NET Decimal is stored as a 12-byte integer, along with a sign and a scaling factor.
So the apparent intent is to determine if the SqlDecimal uses a larger-than-12 byte integer and trigger the overflow.
So this conversion has a bug. It looks like the SqlClient is confused on the byte ordering SQL Server is using, and the last 4 bytes of this buffer are not the 4 least-significant bytes of the 16-byte integer embedded in the decimal.
This number requires uses 12 (base-10) decimal digits to store, so it requires fewer than 12 (base-256) bytes to store.
https://docs.microsoft.com/en-us/dotnet/api/system.decimal?redirectedfrom=MSDN&view=netframework-4.8
The text was updated successfully, but these errors were encountered: