Skip to content

Commit

Permalink
numbers: Swap NUMERIC and DECIMAL (#187)
Browse files Browse the repository at this point in the history
I made a mistake, confusing the names of NUMERIC vs DECIMAL. NUMERIC is
actually the exact type and DECIMAL is the more relaxed type, rather
than the other way around. For prosperity, the *only* difference between
these two types in the SQL standard is:

ISO/IEC 9075-2:2016(E), 6.1, <data type>, Syntax Rules:

> 26) NUMERIC specifies the data type exact numeric, with the decimal
> precision and scale specified by the <precision> and <scale>.
>
> 27) DECIMAL specifies the data type exact numeric, with the decimal
> scale specified by the <scale> and the implementation-defined decimal
> precision equal to or greater than the value of the specified
> <precision>.

I have seen this interpreted as: DECIMAL can use more precision (than
specified) if it's more storage efficient or otherwise favorable for the
engine to do so. This is the reasoning behind vsql's DECIMAL
implementation of storing the raw fraction instead of scaling the number
to the exact NUMERIC value.

This also fixes:

1. All exact numeric types (DECIMAL, NUMERIC, SMALLINT, INTEGER and
BIGINT) were being converted to approximate types for comparison (=, >,
etc). They are now compared as exact values.

2. Nowhere does it say say in the standard that exact values should be
zero padded to the precision (ie. 1.200 for NUMERIC(4, 3)). In fact, it
actually specifies that when converting an exact type to a
variable-length character string it should not do that:

ISO/IEC 9075-2:2016(E), 6.13, <cast specification>, General Rules:

> 12) a) i) Let YP be the shortest character string that conforms to the
> definition of <exact numeric literal> in Subclause 5.3, "<literal>",
> whose scale is the same as the scale of SD and whose interpreted value
> is the absolute value of SV.

It could be argued that the string/display values do not need to follow
this same specification as the situation is different. However, I think
it's going to be less confusing long term if we treat these conversions
the same everywhere.

3. Fixed a bug where casting a DECIMAL to DECIMAL of a higher
precision would not result in more actual precision as expected.
  • Loading branch information
elliotchance committed Dec 30, 2023
1 parent 9895e3b commit 061e53a
Show file tree
Hide file tree
Showing 11 changed files with 164 additions and 102 deletions.
72 changes: 36 additions & 36 deletions docs/numbers.rst
Original file line number Diff line number Diff line change
Expand Up @@ -211,8 +211,8 @@ and precision. Both store their respective values as fractions. For example,
``1.23`` could be represented as ``123/100``.

The main difference between these two types comes down to the allowed
denominators. In short, a ``NUMERIC`` may have any denominator, whereas a
``DECIMAL`` must have a denominator of exactly 10^scale. This can also be
denominators. In short, a ``DECIMAL`` may have any denominator, whereas a
``NUMERIC`` must have a denominator of exactly 10^scale. This can also be
expressed as:

.. list-table::
Expand All @@ -222,31 +222,31 @@ expressed as:
- Numerator
- Denominator

* - ``NUMERIC(scale, precision)``
* - ``DECIMAL(scale, precision)``
- ± 10^scale (exclusive)
- ± 10^scale (exclusive)

* - ``DECIMAL(scale, precision)``
* - ``NUMERIC(scale, precision)``
- ± 10^scale (exclusive)
- 10^scale

When calculations are performed on a ``DECIMAL``, the result from each operation
When calculations are performed on a ``NUMERIC``, the result from each operation
will be normalized to always satisfy this constraint.

This means that a ``DECIMAL`` is always exact at the scale and precision
This means that a ``NUMERIC`` is always exact at the scale and precision
specified and casting to a higher precision will not alter the value. In
contrast, a ``NUMERIC`` promises to have *at least* the precision specified but
contrast, a ``DECIMAL`` promises to have *at least* the precision specified but
the value may change as to be more exact if the precision is increased. This is
best understood with some examples:

.. code-block:: sql
VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL);
-- 1.20
VALUES CAST(1.23 AS NUMERIC(3,2)) / CAST(5 AS NUMERIC) * CAST(5 AS NUMERIC);
-- 1.2
Because:

1. ``1.23 AS DECIMAL(3,2)`` -> ``123/100``
1. ``1.23 AS NUMERIC(3,2)`` -> ``123/100``
2. Normalize denominator -> ``123/100``
3. Divide by ``5`` -> ``123/500``
4. Normalize denominator -> ``24/100``
Expand All @@ -257,63 +257,63 @@ Whereas,

.. code-block:: sql
VALUES CAST(1.23 AS NUMERIC(3,2)) / 5 * 5;
VALUES CAST(1.23 AS DECIMAL(3,2)) / 5 * 5;
-- 1.23
Because:

1. ``1.23 AS NUMERIC(3,2)`` -> ``123/100``
1. ``1.23 AS DECIMAL(3,2)`` -> ``123/100``
2. Divide by ``5`` -> ``123/500``
3. Multiply by ``5`` -> ``615/500``

This may seem like the only difference is that ``NUMERIC`` does not normalize
This may seem like the only difference is that ``DECIMAL`` does not normalize
the denominator, but actually they both need to normalize a denominator that
would be out of bounds. Consider the example:

.. code-block:: sql
VALUES CAST(1.23 AS NUMERIC(3,2)) / 11;
VALUES CAST(1.23 AS DECIMAL(3,2)) / 11;
-- 0.11
1. ``1.23 AS NUMERIC(3,2)`` -> ``123/100``
1. ``1.23 AS DECIMAL(3,2)`` -> ``123/100``
2. Divide by ``11`` -> ``123/1100``
3. Denominator is out of bounds as it cannot be larger than 100. Highest
precision equivalent would be -> ``11/100``

This the same process and result that a ``DECIMAL`` that the equivalent decimal
This the same process and result that a ``NUMERIC`` that the equivalent decimal
operation. Casting to higher precision might result in a different value for
``NUMERIC`` values, for example:
``DECIMAL`` values, for example:

.. code-block:: sql
VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC(5,4)) AS NUMERIC(5,4));
VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL(5,4)) AS DECIMAL(5,4));
-- 0.7142
Because:

1. ``5 AS NUMERIC(3,2)`` -> ``5/1``
1. ``5 AS DECIMAL(3,2)`` -> ``5/1``
2. Divide by ``7`` -> ``5/7``
3. Cast to ``NUMERIC(5,4)`` -> ``5/7``
3. Cast to ``DECIMAL(5,4)`` -> ``5/7``
4. Formatted result based on 4 precision -> ``0.7142``

.. code-block:: sql
VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL) AS DECIMAL(5,4));
VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC) AS NUMERIC(5,4));
-- 0.7100
Because:

1. ``5 AS DECIMAL(3,2)`` -> ``500/100``
1. ``5 AS NUMERIC(3,2)`` -> ``500/100``
2. Divide by ``7`` -> ``500/700``
3. Normalize denominator -> ``71/100``
4. Cast to ``DECIMAL(5,4)`` -> ``7100/10000``
4. Cast to ``NUMERIC(5,4)`` -> ``7100/10000``
5. Formatted result based on 4 precision -> ``0.7100``

Operations Between Exact Types
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

Arithmetic operations can only be performed when both operates are the same
fundamental types, ``NUMERIC`` or ``DECIMAL``, although they do not need to
fundamental types, ``DECIMAL`` or ``NUMERIC``, although they do not need to
share the same scale or precision.

.. list-table::
Expand All @@ -322,27 +322,27 @@ share the same scale or precision.
* - Operation
- Result Type

* - ``NUMERIC(s1, s2) + NUMERIC(s2, p2)``
- ``NUMERIC(MAX(s1, s2), MIN(p1, p2))``
* - ``T(s1, s2) + T(s2, p2)``
- ``T(MAX(s1, s2), MIN(p1, p2))``

* - ``NUMERIC(s1, s2) - NUMERIC(s2, p2)``
- ``NUMERIC(MAX(s1, s2), MIN(p1, p2))``
* - ``T(s1, s2) - T(s2, p2)``
- ``T(MAX(s1, s2), MIN(p1, p2))``

* - ``NUMERIC(s1, s2) * NUMERIC(s2, p2)``
- ``NUMERIC(s1 * s2, p1 + p2)``
* - ``T(s1, s2) * T(s2, p2)``
- ``T(s1 * s2, p1 + p2)``

* - ``NUMERIC(s1, s2) / NUMERIC(s2, p2)``
- ``NUMERIC(s1 * s2, p1 + p2)``
* - ``T(s1, s2) / T(s2, p2)``
- ``T(s1 * s2, p1 + p2)``

Examples:

.. code-block:: sql
VALUES CAST(10.24 AS NUMERIC(4,2)) + CAST(12.123 AS NUMERIC(8,3));
-- 22.36 as NUMERIC(32, 3)
VALUES CAST(10.24 AS DECIMAL(4,2)) + CAST(12.123 AS DECIMAL(8,3));
-- 22.36 as DECIMAL(32, 3)
VALUES CAST(10.24 AS NUMERIC(4,2)) * CAST(12.123 AS NUMERIC(8,3));
-- 124.13952 as NUMERIC(32, 5)
VALUES CAST(10.24 AS DECIMAL(4,2)) * CAST(12.123 AS DECIMAL(8,3));
-- 124.13952 as DECIMAL(32, 5)
Casting
-------
Expand Down
18 changes: 18 additions & 0 deletions tests/comparison.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,3 +33,21 @@ VALUES 1 <= 2;

VALUES 1 <= 1;
-- COL1: TRUE

VALUES 1.0 = 1;
-- COL1: TRUE

VALUES CAST(1.0 AS NUMERIC(5, 3)) = CAST(1 AS NUMERIC(5, 4));
-- COL1: TRUE

VALUES CAST(1.0 AS DECIMAL(5, 3)) = CAST(1 AS DECIMAL(5, 4));
-- COL1: TRUE

VALUES CAST(1.0 AS DECIMAL) = CAST(1 AS DECIMAL);
-- COL1: TRUE

VALUES CAST(1.0 AS DECIMAL) = 1;
-- COL1: TRUE

VALUES CAST(1 AS DECIMAL) = 1.0;
-- COL1: TRUE
56 changes: 33 additions & 23 deletions tests/decimal.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@ SELECT -bar FROM foo;
-- COL1: 1.24

VALUES CAST(1.23 AS DECIMAL(10, 6));
-- COL1: 1.230000
-- COL1: 1.23

VALUES CAST(1.23 AS DECIMAL(10, 2));
-- COL1: 1.23
Expand All @@ -44,19 +44,19 @@ VALUES CAST(-12.34 AS DECIMAL(3, 2));
-- error 22003: numeric value out of range

VALUES CAST(1.23 AS DECIMAL(6, 2)) + CAST(1.5 AS DECIMAL(6, 3));
-- COL1: 2.730
-- COL1: 2.73

VALUES CAST(1.23 AS DECIMAL(6, 2)) - CAST(1.5 AS DECIMAL(6, 3));
-- COL1: -0.270
-- COL1: -0.27

VALUES CAST(1.23 AS DECIMAL(6, 2)) - CAST(-1.5 AS DECIMAL(6, 3));
-- COL1: 2.730
-- COL1: 2.73

VALUES CAST(1.23 AS DECIMAL(6, 2)) * CAST(1.5 AS DECIMAL(6, 3));
-- COL1: 1.84500
-- COL1: 1.845

VALUES CAST(CAST(1.23 AS DECIMAL(6, 2)) * CAST(1.5 AS DECIMAL(6, 3)) AS DECIMAL(6, 4));
-- COL1: 1.8450
-- COL1: 1.845

VALUES CAST(1.24 AS DECIMAL(6, 2)) / CAST(1.5 AS DECIMAL(6, 3));
-- COL1: 0.82666
Expand All @@ -67,29 +67,39 @@ VALUES CAST(1.24 AS DECIMAL(6, 3)) / CAST(1.5 AS DECIMAL(6, 2));
VALUES CAST(CAST(1.24 AS DECIMAL(6, 2)) / CAST(1.5 AS DECIMAL(6, 3)) AS DECIMAL(6, 4));
-- COL1: 0.8266

/* types */
VALUES CAST(1.23 AS DECIMAL(3,2)) / 5;
-- error 42883: operator does not exist: DECIMAL / SMALLINT
-- COL1: 0.24 (DECIMAL(3, 2))

/* types */
VALUES CAST(CAST(1.23 AS DECIMAL(3,2)) / 5 AS DECIMAL(4, 3));
-- COL1: 0.246 (DECIMAL(4, 3))

-- # This is an important case because it's described in detail in the docs for
-- # DECIMAL vs DECIMAL.
VALUES CAST(1.23 AS DECIMAL(3,2)) / 5 * 5;
-- COL1: 1.23

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL) AS DECIMAL(5,4));
-- COL1: 0.7100
-- # DECIMAL vs DECIMAL.
VALUES CAST(1.23 AS DECIMAL(3,2)) / 11;
-- COL1: 0.11

-- # This is an important case because it's described in detail in the docs for
-- # DECIMAL vs DECIMAL.
VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL(5,4)) AS DECIMAL(5,4));
-- COL1: 0.7142

/* types */
VALUES CAST(10.24 AS DECIMAL(4,2)) + CAST(12.123 AS DECIMAL(8,3));
-- COL1: 22.360
-- COL1: 22.36 (DECIMAL(8, 3))

/* types */
VALUES CAST(10.24 AS DECIMAL(4,2)) * CAST(12.123 AS DECIMAL(8,3));
-- COL1: 124.13952
-- COL1: 124.13952 (DECIMAL(32, 5))

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL);
-- COL1: 1.20
VALUES CAST(1 AS DECIMAL(2,1)) / CAST(3 AS DECIMAL(2,1));
-- COL1: 0.33

VALUES CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL(5,4));
-- COL1: 0.714285

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL);
-- COL1: 1.20
VALUES CAST(CAST(1 AS DECIMAL(2,1)) / CAST(3 AS DECIMAL(2,1)) AS DECIMAL(10, 8));
-- COL1: 0.33333333
40 changes: 22 additions & 18 deletions tests/numeric.sql
Original file line number Diff line number Diff line change
Expand Up @@ -77,28 +77,32 @@ VALUES CAST(CAST(1.24 AS NUMERIC(6, 2)) / CAST(1.5 AS NUMERIC(6, 3)) AS NUMERIC(
VALUES CAST(1.23 AS NUMERIC(3,2)) / 5;
-- COL1: 0.24

VALUES CAST(CAST(1.23 AS NUMERIC(3,2)) / 5 AS NUMERIC(4, 3));
-- COL1: 0.246

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(1.23 AS NUMERIC(3,2)) / 5 * 5;
-- COL1: 1.23
-- # NUMERIC vs NUMERIC.
VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC) AS NUMERIC(5,4));
-- COL1: 0.71

VALUES CAST(10.24 AS NUMERIC(4,2)) + CAST(12.123 AS NUMERIC(8,3));
-- COL1: 22.36

VALUES CAST(10.24 AS NUMERIC(4,2)) * CAST(12.123 AS NUMERIC(8,3));
-- COL1: 124.13952

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(1.23 AS NUMERIC(3,2)) / 11;
-- COL1: 0.11
-- # NUMERIC vs NUMERIC.
VALUES CAST(1.23 AS NUMERIC(3,2)) / CAST(5 AS NUMERIC) * CAST(5 AS NUMERIC);
-- COL1: 1.2

VALUES CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC(5,4));
-- COL1: 0.714285

-- # This is an important case because it's described in detail in the docs for
-- # NUMERIC vs DECIMAL.
VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC(5,4)) AS NUMERIC(5,4));
-- COL1: 0.7142
-- # NUMERIC vs NUMERIC.
VALUES CAST(1.23 AS NUMERIC(3,2)) / CAST(5 AS NUMERIC) * CAST(5 AS NUMERIC);
-- COL1: 1.2

/* types */
VALUES CAST(10.24 AS NUMERIC(4,2)) + CAST(12.123 AS NUMERIC(8,3));
-- COL1: 22.36 (NUMERIC(8, 3))
VALUES CAST(1 AS NUMERIC(2,1)) / CAST(3 AS NUMERIC(2,1));
-- COL1: 0.33

/* types */
VALUES CAST(10.24 AS NUMERIC(4,2)) * CAST(12.123 AS NUMERIC(8,3));
-- COL1: 124.13952 (NUMERIC(32, 5))
VALUES CAST(CAST(1 AS NUMERIC(2,1)) / CAST(3 AS NUMERIC(2,1)) AS NUMERIC(10, 8));
-- COL1: 0.33
22 changes: 18 additions & 4 deletions vsql/numeric.v
Original file line number Diff line number Diff line change
Expand Up @@ -298,13 +298,13 @@ fn (n Numeric) normalize_denominator(typ Type) Numeric {
denominator := big.integer_from_int(10).pow(u32(typ.scale))
max_denominator := big.integer_from_int(10).pow(u32(typ.scale + 1)) - big.one_int

// NUMERICAL only need to scale when the denominator goes beyond the bounds.
if typ.typ == .is_numeric && n.denominator > max_denominator {
// DECIMAL only need to scale when the denominator goes beyond the bounds.
if typ.typ == .is_decimal && n.denominator > max_denominator {
return n.scale_numerator(denominator)
}

// DECIMAL always needs to have a fixed denominator.
if typ.typ == .is_decimal && n.denominator != denominator {
// NUMERIC always needs to have a fixed denominator.
if typ.typ == .is_numeric && n.denominator != denominator {
return n.scale_numerator(denominator)
}

Expand All @@ -326,6 +326,20 @@ fn common_denominator(n1 Numeric, n2 Numeric) (Numeric, Numeric) {
return n3, n4
}

fn (n Numeric) compare(n2 Numeric) CompareResult {
n3, n4 := common_denominator(n, n2)

if n3.numerator < n4.numerator {
return .is_less
}

if n3.numerator > n4.numerator {
return .is_greater
}

return .is_equal
}

fn (n Numeric) equals(n2 Numeric) bool {
n3, n4 := common_denominator(n, n2)

Expand Down
4 changes: 4 additions & 0 deletions vsql/operators.v
Original file line number Diff line number Diff line change
Expand Up @@ -277,5 +277,9 @@ fn binary_decimal_multiply_decimal(conn &Connection, a Value, b Value) !Value {
}

fn binary_decimal_divide_decimal(conn &Connection, a Value, b Value) !Value {
if b.as_f64()! == 0 {
return sqlstate_22012() // division by zero
}

return new_decimal_value_from_numeric(a.numeric_value().divide(b.numeric_value())!)
}

0 comments on commit 061e53a

Please sign in to comment.