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»»

Difference between decimal and smallmoney Expand / Collapse
Author
Message
Posted Tuesday, September 25, 2012 9:09 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Wednesday, July 16, 2014 3:21 AM
Points: 92, Visits: 373
Hi

smallmoney type takes up to 4 bytes.
Monetary data values from -214,748.3648 through +214,748.3647, with accuracy to a ten-thousandth of a monetary unit.

Yet decimal(9,4) takes 5 bytes (as I understand it) yet doesn't store as large a range.

decimal(9,4) can only store 21474.3647 but use one more byte





Post #1364112
Posted Tuesday, September 25, 2012 9:16 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Friday, July 25, 2014 12:09 PM
Points: 429, Visits: 334
So...what's your question?

Roland Alexander
The Developing World


There are two means of refuge from the miseries of life: music and cats. ~ Albert Schweitzer
Post #1364118
Posted Tuesday, September 25, 2012 9:20 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Wednesday, July 16, 2014 3:21 AM
Points: 92, Visits: 373
2 datatypes, one can store more digits in less bytes than the other, I must of missed something obvious here..

I'm asking as I wanted to use decimal (9,3) for prices, yet smallmoney uses one less byte and can store bigger numbers.

Post #1364123
Posted Tuesday, September 25, 2012 9:26 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Friday, July 25, 2014 12:09 PM
Points: 429, Visits: 334
Then the short answer is, use the variable with the smallest footprint that meets your requirements: in this case, smallmoney.

As to the one-byte difference, I can't say definitively as I haven't researched it, but I'd say it has something to do with the need for the decimal type to have varying scale, whereas money and smallmoney are fixed at scale = 4. Research BOL for "datatypes" for more info.


Roland Alexander
The Developing World


There are two means of refuge from the miseries of life: music and cats. ~ Albert Schweitzer
Post #1364131
Posted Tuesday, September 25, 2012 9:49 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 6:37 AM
Points: 1,868, Visits: 2,984
Decimal(9,3) can store -999,999.999 to 999,999.999
Decimal(9,4) is -99,999.9999 to 99,999.9999

Not sure, but I think they're stored differently internally - decimal as an integer* with a factor of 10 multiplier, money as a standard integer.
E.g. in decimal(9,4), 12345.6789 is stored as 123456789 x 10^-4
*(Integer here means the mathematical definition, not the datatype).

As precision increases, the bytes needed to store the integer increase to accommodate the maximum possible value.

4 bytes is enough to store 999,999,999 but not 9,999,999,999
Perhaps the extra byte stores the factor of 10 to multiply by?

For smallmoney, you'll notice the maximum value of a 4-byte integer is 2,147,483,647, which equals 214,748.3647 x 10^4, the maximum value of smallmoney. Don't need to store the factor of 10 multiplier as it's always -4 in smallmoney.
Post #1364150
Posted Tuesday, September 25, 2012 10:23 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 1:55 AM
Points: 11,192, Visits: 11,095
terry999 (9/25/2012)

smallmoney type takes up to 4 bytes
decimal(9,4) can only store 21474.3647 but use one more byte

The ranges of the two types have been discussed already, but there is another consideration:

-- Result is $1.0000 typed as smallmoney
DECLARE @credit smallmoney = $1.99;
SELECT @credit / 10000 * 10000;
GO
-- Result is 1.9900000000 typed as decimal (21, 10)
DECLARE @credit decimal(9,4) = 1.99;
SELECT @credit / 10000 * 10000;

This may or may not be important to you, but the characteristics of the data type might be more interesting than saving a byte here or there. Indeed, there may be no byte to save if row compression is active, or if the extra byte per row does not result in at least one row having to be stored on a separate data page.




Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1364170
Posted Tuesday, September 25, 2012 3:32 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Wednesday, July 16, 2014 3:21 AM
Points: 92, Visits: 373
Makes sense to me.
Post #1364318
Posted Wednesday, September 26, 2012 1:35 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Sunday, July 20, 2014 11:55 AM
Points: 1,945, Visits: 2,860
2 datatypes, one can store more digits in less bytes than the other, I must of missed something obvious here.. I'm asking as I wanted to use decimal (9,3) for prices, yet smallmoney uses one less byte and can store bigger numbers.


The proprietary MONEY data types are leftovers from the 1970's and Sybase. They do display formatting in the database in violation of the principle of a tiered architecture; they do not port; they do incorrect math by rounding too soon. (Google it!)

The DECIMAL(s,p) types allow you to adjust the precision to the legally required limits. Ask your accounting department, but 5 decimals shows up in GAAP and EU regulations.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1364482
Posted Wednesday, September 26, 2012 8:20 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, July 4, 2014 3:55 AM
Points: 2,836, Visits: 5,062

...
The ranges of the two types have been discussed already, but there is another consideration:

-- Result is $1.0000 typed as smallmoney
DECLARE @credit smallmoney = $1.99;
SELECT @credit / 10000 * 10000;
GO
-- Result is 1.9900000000 typed as decimal (21, 10)
DECLARE @credit decimal(9,4) = 1.99;
SELECT @credit / 10000 * 10000;

...


In the above example by Paul White, you can see where the rounding happens and how it can potentially cause issues.
So, If you work with monetary datatypes you should understand how SQL works with them and when rounding is performed. Try this one:

-- Result is $1.99 typed as smallmoney
DECLARE @credit smallmoney = $1.99;
SELECT @credit * 10000 / 10000;

The reason it works fine for decimal is that SQL converts result of decimal(9,4) division by integer to decimal(21,10)

Check this one:


SELECT 1.99 / 10000.00
SELECT 1.99 / 10000.0
SELECT 1.99 / 10000
SELECT 1.9900 / 10000.00
SELECT 1.9900 / 10000.0
SELECT 1.9900 / 10000


So, I do prefer working with decimals as there are less thing to worry about, but sometimes you stuck with what you have. So, you should know implications and ways around.


_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1364721
Posted Wednesday, September 26, 2012 8:46 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 1:55 AM
Points: 11,192, Visits: 11,095
Eugene Elutin (9/26/2012)
If you work with monetary datatypes you should understand how SQL works with them and when rounding is performed.

Are you talking to me?




Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1364750
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse