From 5e7c3d91bf24a212b42c912234c6cb37d75e0292 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Fri, 3 Jul 2015 17:04:39 -0400 Subject: [PATCH] Add documentation and regression tests concerning rounding of numerics. Michael Paquier, reviewed by Fabien Coelho --- doc/src/sgml/datatype.sgml | 25 +++++++++++++++++++ src/test/regress/expected/int2.out | 20 +++++++++++++++ src/test/regress/expected/int4.out | 20 +++++++++++++++ .../expected/int8-exp-three-digits.out | 20 +++++++++++++++ src/test/regress/expected/int8.out | 20 +++++++++++++++ src/test/regress/expected/numeric.out | 24 ++++++++++++++++++ src/test/regress/sql/int2.sql | 10 ++++++++ src/test/regress/sql/int4.sql | 10 ++++++++ src/test/regress/sql/int8.sql | 10 ++++++++ src/test/regress/sql/numeric.sql | 10 ++++++++ 10 files changed, 169 insertions(+) diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml index 9d5ce953f1..8e13555a3a 100644 --- a/doc/src/sgml/datatype.sgml +++ b/doc/src/sgml/datatype.sgml @@ -612,6 +612,31 @@ NUMERIC equivalent. Both types are part of the SQL standard. + + + When rounding values, the numeric type rounds ties away + from zero, while (on most machines) the real + and double precision types round ties to the nearest even + number. For example: + + +SELECT x, + round(x::numeric) AS num_round, + round(x::double precision) AS dbl_round +FROM generate_series(-3.5, 3.5, 1) as x; + x | num_round | dbl_round +------+-----------+----------- + -3.5 | -4 | -4 + -2.5 | -3 | -2 + -1.5 | -2 | -2 + -0.5 | -1 | -0 + 0.5 | 1 | 0 + 1.5 | 2 | 2 + 2.5 | 3 | 2 + 3.5 | 4 | 4 +(8 rows) + + diff --git a/src/test/regress/expected/int2.out b/src/test/regress/expected/int2.out index 311fe730a5..3ea4ed93a0 100644 --- a/src/test/regress/expected/int2.out +++ b/src/test/regress/expected/int2.out @@ -286,3 +286,23 @@ FROM (VALUES (-2.5::float8), 2.5 | 2 (7 rows) +-- check rounding when casting from numeric +SELECT x, x::int2 AS int2_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); + x | int2_value +------+------------ + -2.5 | -3 + -1.5 | -2 + -0.5 | -1 + 0.0 | 0 + 0.5 | 1 + 1.5 | 2 + 2.5 | 3 +(7 rows) + diff --git a/src/test/regress/expected/int4.out b/src/test/regress/expected/int4.out index 83fe022d7f..372fd4d94c 100644 --- a/src/test/regress/expected/int4.out +++ b/src/test/regress/expected/int4.out @@ -383,3 +383,23 @@ FROM (VALUES (-2.5::float8), 2.5 | 2 (7 rows) +-- check rounding when casting from numeric +SELECT x, x::int4 AS int4_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); + x | int4_value +------+------------ + -2.5 | -3 + -1.5 | -2 + -0.5 | -1 + 0.0 | 0 + 0.5 | 1 + 1.5 | 2 + 2.5 | 3 +(7 rows) + diff --git a/src/test/regress/expected/int8-exp-three-digits.out b/src/test/regress/expected/int8-exp-three-digits.out index a4f0cc23ec..7ad4dcea0f 100644 --- a/src/test/regress/expected/int8-exp-three-digits.out +++ b/src/test/regress/expected/int8-exp-three-digits.out @@ -866,3 +866,23 @@ FROM (VALUES (-2.5::float8), 2.5 | 2 (7 rows) +-- check rounding when casting from numeric +SELECT x, x::int8 AS int8_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); + x | int8_value +------+------------ + -2.5 | -3 + -1.5 | -2 + -0.5 | -1 + 0.0 | 0 + 0.5 | 1 + 1.5 | 2 + 2.5 | 3 +(7 rows) + diff --git a/src/test/regress/expected/int8.out b/src/test/regress/expected/int8.out index da8be51886..ed0bd34221 100644 --- a/src/test/regress/expected/int8.out +++ b/src/test/regress/expected/int8.out @@ -866,3 +866,23 @@ FROM (VALUES (-2.5::float8), 2.5 | 2 (7 rows) +-- check rounding when casting from numeric +SELECT x, x::int8 AS int8_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); + x | int8_value +------+------------ + -2.5 | -3 + -1.5 | -2 + -0.5 | -1 + 0.0 | 0 + 0.5 | 1 + 1.5 | 2 + 2.5 | 3 +(7 rows) + diff --git a/src/test/regress/expected/numeric.out b/src/test/regress/expected/numeric.out index 9d6814564d..e6ee548e7c 100644 --- a/src/test/regress/expected/numeric.out +++ b/src/test/regress/expected/numeric.out @@ -730,6 +730,30 @@ SELECT a, ceil(a), ceiling(a), floor(a), round(a) FROM ceil_floor_round; (7 rows) DROP TABLE ceil_floor_round; +-- Check rounding, it should round ties away from zero. +SELECT i as pow, + round((-2.5 * 10 ^ i)::numeric, -i), + round((-1.5 * 10 ^ i)::numeric, -i), + round((-0.5 * 10 ^ i)::numeric, -i), + round((0.5 * 10 ^ i)::numeric, -i), + round((1.5 * 10 ^ i)::numeric, -i), + round((2.5 * 10 ^ i)::numeric, -i) +FROM generate_series(-5,5) AS t(i); + pow | round | round | round | round | round | round +-----+----------+----------+----------+---------+---------+--------- + -5 | -0.00003 | -0.00002 | -0.00001 | 0.00001 | 0.00002 | 0.00003 + -4 | -0.0003 | -0.0002 | -0.0001 | 0.0001 | 0.0002 | 0.0003 + -3 | -0.003 | -0.002 | -0.001 | 0.001 | 0.002 | 0.003 + -2 | -0.03 | -0.02 | -0.01 | 0.01 | 0.02 | 0.03 + -1 | -0.3 | -0.2 | -0.1 | 0.1 | 0.2 | 0.3 + 0 | -3 | -2 | -1 | 1 | 2 | 3 + 1 | -30 | -20 | -10 | 10 | 20 | 30 + 2 | -300 | -200 | -100 | 100 | 200 | 300 + 3 | -3000 | -2000 | -1000 | 1000 | 2000 | 3000 + 4 | -30000 | -20000 | -10000 | 10000 | 20000 | 30000 + 5 | -300000 | -200000 | -100000 | 100000 | 200000 | 300000 +(11 rows) + -- Testing for width_bucket(). For convenience, we test both the -- numeric and float8 versions of the function in this file. -- errors diff --git a/src/test/regress/sql/int2.sql b/src/test/regress/sql/int2.sql index 5e9774e922..7dbafb6dac 100644 --- a/src/test/regress/sql/int2.sql +++ b/src/test/regress/sql/int2.sql @@ -102,3 +102,13 @@ FROM (VALUES (-2.5::float8), (0.5::float8), (1.5::float8), (2.5::float8)) t(x); + +-- check rounding when casting from numeric +SELECT x, x::int2 AS int2_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); diff --git a/src/test/regress/sql/int4.sql b/src/test/regress/sql/int4.sql index d188140525..f014cb2d32 100644 --- a/src/test/regress/sql/int4.sql +++ b/src/test/regress/sql/int4.sql @@ -145,3 +145,13 @@ FROM (VALUES (-2.5::float8), (0.5::float8), (1.5::float8), (2.5::float8)) t(x); + +-- check rounding when casting from numeric +SELECT x, x::int4 AS int4_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); diff --git a/src/test/regress/sql/int8.sql b/src/test/regress/sql/int8.sql index 69723759fe..e890452236 100644 --- a/src/test/regress/sql/int8.sql +++ b/src/test/regress/sql/int8.sql @@ -215,3 +215,13 @@ FROM (VALUES (-2.5::float8), (0.5::float8), (1.5::float8), (2.5::float8)) t(x); + +-- check rounding when casting from numeric +SELECT x, x::int8 AS int8_value +FROM (VALUES (-2.5::numeric), + (-1.5::numeric), + (-0.5::numeric), + (0.0::numeric), + (0.5::numeric), + (1.5::numeric), + (2.5::numeric)) t(x); diff --git a/src/test/regress/sql/numeric.sql b/src/test/regress/sql/numeric.sql index 1633e4c375..982287c33a 100644 --- a/src/test/regress/sql/numeric.sql +++ b/src/test/regress/sql/numeric.sql @@ -667,6 +667,16 @@ INSERT INTO ceil_floor_round VALUES ('-0.000001'); SELECT a, ceil(a), ceiling(a), floor(a), round(a) FROM ceil_floor_round; DROP TABLE ceil_floor_round; +-- Check rounding, it should round ties away from zero. +SELECT i as pow, + round((-2.5 * 10 ^ i)::numeric, -i), + round((-1.5 * 10 ^ i)::numeric, -i), + round((-0.5 * 10 ^ i)::numeric, -i), + round((0.5 * 10 ^ i)::numeric, -i), + round((1.5 * 10 ^ i)::numeric, -i), + round((2.5 * 10 ^ i)::numeric, -i) +FROM generate_series(-5,5) AS t(i); + -- Testing for width_bucket(). For convenience, we test both the -- numeric and float8 versions of the function in this file.