Difference between decimal and smallmoney

  • 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

  • So...what's your question?

    Roland Alexander 
    The Monday Morning DBA 
    There are two means of refuge from the miseries of life: music and cats. ~ Albert Schweitzer

  • 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.

  • 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 Monday Morning DBA 
    There are two means of refuge from the miseries of life: music and cats. ~ Albert Schweitzer

  • 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.

  • 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.

  • Makes sense to me.

  • ...

    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!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • 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?

  • SQL Kiwi (9/26/2012)


    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?

    No! Sorry, I was not explicit enough. My post addressed to OP.

    :blush:

    Please check if my edit did make a change...

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

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (9/26/2012)


    No! Sorry, I was not explicit enough. My post addressed to OP. :blush:

    No worries, just checking in case I was expected to respond.

Viewing 11 posts - 1 through 10 (of 10 total)

You must be logged in to reply to this topic. Login to reply