mirror of
https://github.com/postgres/postgres.git
synced 2026-02-27 03:40:28 -05:00
The cash_div_intX functions applied rint() to the result of the division. That's not merely useless (because the result is already an integer) but it causes precision loss for values larger than 2^52 or so, because of the forced conversion to float8. On the other hand, the cash_mul_fltX functions neglected to apply rint() to their multiplication results, thus possibly causing off-by-one outputs. Per C standard, arithmetic between any integral value and a float value is performed in float format. Thus, cash_mul_flt4 and cash_div_flt4 produced answers good to only about six digits, even when the float value is exact. We can improve matters noticeably by widening the float inputs to double. (It's tempting to consider using "long double" arithmetic if available, but that's probably too much of a stretch for a back-patched fix.) Also, document that cash_div_intX operators truncate rather than round. Per bug #14663 from Richard Pistole. Back-patch to all supported branches. Discussion: https://postgr.es/m/22403.1495223615@sss.pgh.pa.us
127 lines
3.6 KiB
SQL
127 lines
3.6 KiB
SQL
--
|
|
-- MONEY
|
|
--
|
|
|
|
CREATE TABLE money_data (m money);
|
|
|
|
INSERT INTO money_data VALUES ('123');
|
|
SELECT * FROM money_data;
|
|
SELECT m + '123' FROM money_data;
|
|
SELECT m + '123.45' FROM money_data;
|
|
SELECT m - '123.45' FROM money_data;
|
|
SELECT m / '2'::money FROM money_data;
|
|
SELECT m * 2 FROM money_data;
|
|
SELECT 2 * m FROM money_data;
|
|
SELECT m / 2 FROM money_data;
|
|
SELECT m * 2::int2 FROM money_data;
|
|
SELECT 2::int2 * m FROM money_data;
|
|
SELECT m / 2::int2 FROM money_data;
|
|
SELECT m * 2::int8 FROM money_data;
|
|
SELECT 2::int8 * m FROM money_data;
|
|
SELECT m / 2::int8 FROM money_data;
|
|
SELECT m * 2::float8 FROM money_data;
|
|
SELECT 2::float8 * m FROM money_data;
|
|
SELECT m / 2::float8 FROM money_data;
|
|
SELECT m * 2::float4 FROM money_data;
|
|
SELECT 2::float4 * m FROM money_data;
|
|
SELECT m / 2::float4 FROM money_data;
|
|
|
|
-- All true
|
|
SELECT m = '$123.00' FROM money_data;
|
|
SELECT m != '$124.00' FROM money_data;
|
|
SELECT m <= '$123.00' FROM money_data;
|
|
SELECT m >= '$123.00' FROM money_data;
|
|
SELECT m < '$124.00' FROM money_data;
|
|
SELECT m > '$122.00' FROM money_data;
|
|
|
|
-- All false
|
|
SELECT m = '$123.01' FROM money_data;
|
|
SELECT m != '$123.00' FROM money_data;
|
|
SELECT m <= '$122.99' FROM money_data;
|
|
SELECT m >= '$123.01' FROM money_data;
|
|
SELECT m > '$124.00' FROM money_data;
|
|
SELECT m < '$122.00' FROM money_data;
|
|
|
|
SELECT cashlarger(m, '$124.00') FROM money_data;
|
|
SELECT cashsmaller(m, '$124.00') FROM money_data;
|
|
SELECT cash_words(m) FROM money_data;
|
|
SELECT cash_words(m + '1.23') FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.45');
|
|
SELECT * FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.451');
|
|
SELECT * FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.454');
|
|
SELECT * FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.455');
|
|
SELECT * FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.456');
|
|
SELECT * FROM money_data;
|
|
|
|
DELETE FROM money_data;
|
|
INSERT INTO money_data VALUES ('$123.459');
|
|
SELECT * FROM money_data;
|
|
|
|
-- input checks
|
|
SELECT '1234567890'::money;
|
|
SELECT '12345678901234567'::money;
|
|
SELECT '123456789012345678'::money;
|
|
SELECT '9223372036854775807'::money;
|
|
SELECT '-12345'::money;
|
|
SELECT '-1234567890'::money;
|
|
SELECT '-12345678901234567'::money;
|
|
SELECT '-123456789012345678'::money;
|
|
SELECT '-9223372036854775808'::money;
|
|
|
|
-- special characters
|
|
SELECT '(1)'::money;
|
|
SELECT '($123,456.78)'::money;
|
|
|
|
-- documented minimums and maximums
|
|
SELECT '-92233720368547758.08'::money;
|
|
SELECT '92233720368547758.07'::money;
|
|
|
|
SELECT '-92233720368547758.09'::money;
|
|
SELECT '92233720368547758.08'::money;
|
|
|
|
-- rounding
|
|
SELECT '-92233720368547758.085'::money;
|
|
SELECT '92233720368547758.075'::money;
|
|
|
|
-- rounding vs. truncation in division
|
|
SELECT '878.08'::money / 11::float8;
|
|
SELECT '878.08'::money / 11::float4;
|
|
SELECT '878.08'::money / 11::bigint;
|
|
SELECT '878.08'::money / 11::int;
|
|
SELECT '878.08'::money / 11::smallint;
|
|
|
|
-- check for precision loss in division
|
|
SELECT '90000000000000099.00'::money / 10::bigint;
|
|
SELECT '90000000000000099.00'::money / 10::int;
|
|
SELECT '90000000000000099.00'::money / 10::smallint;
|
|
|
|
-- Cast int4/int8/numeric to money
|
|
SELECT 1234567890::money;
|
|
SELECT 12345678901234567::money;
|
|
SELECT (-12345)::money;
|
|
SELECT (-1234567890)::money;
|
|
SELECT (-12345678901234567)::money;
|
|
SELECT 1234567890::int4::money;
|
|
SELECT 12345678901234567::int8::money;
|
|
SELECT 12345678901234567::numeric::money;
|
|
SELECT (-1234567890)::int4::money;
|
|
SELECT (-12345678901234567)::int8::money;
|
|
SELECT (-12345678901234567)::numeric::money;
|
|
|
|
-- Cast from money
|
|
SELECT '12345678901234567'::money::numeric;
|
|
SELECT '-12345678901234567'::money::numeric;
|