From fa854112fc3d5fae1da071bd647eb777eb584c2e Mon Sep 17 00:00:00 2001
From: Tom Lane <tgl@sss.pgh.pa.us>
Date: Fri, 26 Jul 2019 11:59:00 -0400
Subject: [PATCH] Fix loss of fractional digits for large values in
 cash_numeric().

Money values exceeding about 18 digits (depending on lc_monetary)
could be inaccurately converted to numeric, due to select_div_scale()
deciding it didn't need to compute any fractional digits.  Force
its hand by setting the dscale of one division input to equal the
number of fractional digits we need.

In passing, rearrange the logic to not do useless work in locales
where money values are considered integral.

Per bug #15925 from Slawomir Chodnicki.  Back-patch to all supported
branches.

Discussion: https://postgr.es/m/15925-da9953e2674bb5c8@postgresql.org
---
 src/backend/utils/adt/cash.c        | 58 +++++++++++++++++++----------
 src/test/regress/expected/money.out | 16 +++++++-
 src/test/regress/sql/money.sql      |  6 ++-
 3 files changed, 58 insertions(+), 22 deletions(-)

diff --git a/src/backend/utils/adt/cash.c b/src/backend/utils/adt/cash.c
index 7bbc634bd2b..2e1662a2a6c 100644
--- a/src/backend/utils/adt/cash.c
+++ b/src/backend/utils/adt/cash.c
@@ -1033,13 +1033,8 @@ Datum
 cash_numeric(PG_FUNCTION_ARGS)
 {
 	Cash		money = PG_GETARG_CASH(0);
-	Numeric		result;
+	Datum		result;
 	int			fpoint;
-	int64		scale;
-	int			i;
-	Datum		amount;
-	Datum		numeric_scale;
-	Datum		quotient;
 	struct lconv *lconvert = PGLC_localeconv();
 
 	/* see comments about frac_digits in cash_in() */
@@ -1047,22 +1042,45 @@ cash_numeric(PG_FUNCTION_ARGS)
 	if (fpoint < 0 || fpoint > 10)
 		fpoint = 2;
 
-	/* compute required scale factor */
-	scale = 1;
-	for (i = 0; i < fpoint; i++)
-		scale *= 10;
-
-	/* form the result as money / scale */
-	amount = DirectFunctionCall1(int8_numeric, Int64GetDatum(money));
-	numeric_scale = DirectFunctionCall1(int8_numeric, Int64GetDatum(scale));
-	quotient = DirectFunctionCall2(numeric_div, amount, numeric_scale);
+	/* convert the integral money value to numeric */
+	result = DirectFunctionCall1(int8_numeric, Int64GetDatum(money));
 
-	/* forcibly round to exactly the intended number of digits */
-	result = DatumGetNumeric(DirectFunctionCall2(numeric_round,
-												 quotient,
-												 Int32GetDatum(fpoint)));
+	/* scale appropriately, if needed */
+	if (fpoint > 0)
+	{
+		int64		scale;
+		int			i;
+		Datum		numeric_scale;
+		Datum		quotient;
+
+		/* compute required scale factor */
+		scale = 1;
+		for (i = 0; i < fpoint; i++)
+			scale *= 10;
+		numeric_scale = DirectFunctionCall1(int8_numeric,
+											Int64GetDatum(scale));
+
+		/*
+		 * Given integral inputs approaching INT64_MAX, select_div_scale()
+		 * might choose a result scale of zero, causing loss of fractional
+		 * digits in the quotient.  We can ensure an exact result by setting
+		 * the dscale of either input to be at least as large as the desired
+		 * result scale.  numeric_round() will do that for us.
+		 */
+		numeric_scale = DirectFunctionCall2(numeric_round,
+											numeric_scale,
+											Int32GetDatum(fpoint));
+
+		/* Now we can safely divide ... */
+		quotient = DirectFunctionCall2(numeric_div, result, numeric_scale);
+
+		/* ... and forcibly round to exactly the intended number of digits */
+		result = DirectFunctionCall2(numeric_round,
+									 quotient,
+									 Int32GetDatum(fpoint));
+	}
 
-	PG_RETURN_NUMERIC(result);
+	PG_RETURN_DATUM(result);
 }
 
 /* numeric_cash()
diff --git a/src/test/regress/expected/money.out b/src/test/regress/expected/money.out
index ab86595fc02..fc71a72fed3 100644
--- a/src/test/regress/expected/money.out
+++ b/src/test/regress/expected/money.out
@@ -1,6 +1,8 @@
 --
 -- MONEY
 --
+-- Note that we assume lc_monetary has been set to C.
+--
 CREATE TABLE money_data (m money);
 INSERT INTO money_data VALUES ('123');
 SELECT * FROM money_data;
@@ -476,7 +478,7 @@ SELECT (-12345678901234567)::numeric::money;
  -$12,345,678,901,234,567.00
 (1 row)
 
--- Cast from money
+-- Cast from money to numeric
 SELECT '12345678901234567'::money::numeric;
        numeric        
 ----------------------
@@ -489,3 +491,15 @@ SELECT '-12345678901234567'::money::numeric;
  -12345678901234567.00
 (1 row)
 
+SELECT '92233720368547758.07'::money::numeric;
+       numeric        
+----------------------
+ 92233720368547758.07
+(1 row)
+
+SELECT '-92233720368547758.08'::money::numeric;
+        numeric        
+-----------------------
+ -92233720368547758.08
+(1 row)
+
diff --git a/src/test/regress/sql/money.sql b/src/test/regress/sql/money.sql
index 37b9ecce1fc..5e746286c90 100644
--- a/src/test/regress/sql/money.sql
+++ b/src/test/regress/sql/money.sql
@@ -1,6 +1,8 @@
 --
 -- MONEY
 --
+-- Note that we assume lc_monetary has been set to C.
+--
 
 CREATE TABLE money_data (m money);
 
@@ -122,6 +124,8 @@ SELECT (-1234567890)::int4::money;
 SELECT (-12345678901234567)::int8::money;
 SELECT (-12345678901234567)::numeric::money;
 
--- Cast from money
+-- Cast from money to numeric
 SELECT '12345678901234567'::money::numeric;
 SELECT '-12345678901234567'::money::numeric;
+SELECT '92233720368547758.07'::money::numeric;
+SELECT '-92233720368547758.08'::money::numeric;
-- 
GitLab