Support infinity and -infinity in the numeric data type.

Add infinities that behave the same as they do in the floating-point
data types.  Aside from any intrinsic usefulness these may have,
this closes an important gap in our ability to convert floating
values to numeric and/or replace float-based APIs with numeric.

The new values are represented by bit patterns that were formerly
not used (although old code probably would take them for NaNs).
So there shouldn't be any pg_upgrade hazard.

Patch by me, reviewed by Dean Rasheed and Andrew Gierth

Discussion: https://postgr.es/m/606717.1591924582@sss.pgh.pa.us
This commit is contained in:
Tom Lane 2020-07-22 19:19:44 -04:00
parent 9e108984fb
commit a57d312a77
12 changed files with 2252 additions and 381 deletions

View File

@ -227,10 +227,8 @@ SV_to_JsonbValue(SV *in, JsonbParseState **jsonb_state, bool is_elem)
/*
* jsonb doesn't allow infinity or NaN (per JSON
* specification), but the numeric type that is used for the
* storage accepts NaN, so we have to prevent it here
* explicitly. We don't really have to check for isinf()
* here, as numeric doesn't allow it and it would be caught
* later, but it makes for a nicer error message.
* storage accepts those, so we have to reject them here
* explicitly.
*/
if (isinf(nval))
ereport(ERROR,

View File

@ -387,14 +387,17 @@ PLyNumber_ToJsonbValue(PyObject *obj, JsonbValue *jbvNum)
pfree(str);
/*
* jsonb doesn't allow NaN (per JSON specification), so we have to prevent
* it here explicitly. (Infinity is also not allowed in jsonb, but
* numeric_in above already catches that.)
* jsonb doesn't allow NaN or infinity (per JSON specification), so we
* have to reject those here explicitly.
*/
if (numeric_is_nan(num))
ereport(ERROR,
(errcode(ERRCODE_NUMERIC_VALUE_OUT_OF_RANGE),
errmsg("cannot convert NaN to jsonb")));
if (numeric_is_inf(num))
ereport(ERROR,
(errcode(ERRCODE_NUMERIC_VALUE_OUT_OF_RANGE),
errmsg("cannot convert infinity to jsonb")));
jbvNum->type = jbvNumeric;
jbvNum->val.numeric = num;

View File

@ -554,9 +554,9 @@ NUMERIC(<replaceable>precision</replaceable>)
<programlisting>
NUMERIC
</programlisting>
without any precision or scale creates a column in which numeric
values of any precision and scale can be stored, up to the
implementation limit on precision. A column of this kind will
without any precision or scale creates an <quote>unconstrained
numeric</quote> column in which numeric values of any length can be
stored, up to the implementation limits. A column of this kind will
not coerce input values to any particular scale, whereas
<type>numeric</type> columns with a declared scale will coerce
input values to that scale. (The <acronym>SQL</acronym> standard
@ -568,10 +568,10 @@ NUMERIC
<note>
<para>
The maximum allowed precision when explicitly specified in the
type declaration is 1000; <type>NUMERIC</type> without a specified
precision is subject to the limits described in <xref
linkend="datatype-numeric-table"/>.
The maximum precision that can be explicitly specified in
a <type>NUMERIC</type> type declaration is 1000. An
unconstrained <type>NUMERIC</type> column is subject to the limits
described in <xref linkend="datatype-numeric-table"/>.
</para>
</note>
@ -593,6 +593,11 @@ NUMERIC
plus three to eight bytes overhead.
</para>
<indexterm>
<primary>infinity</primary>
<secondary>numeric (data type)</secondary>
</indexterm>
<indexterm>
<primary>NaN</primary>
<see>not a number</see>
@ -604,13 +609,44 @@ NUMERIC
</indexterm>
<para>
In addition to ordinary numeric values, the <type>numeric</type>
type allows the special value <literal>NaN</literal>, meaning
<quote>not-a-number</quote>. Any operation on <literal>NaN</literal>
yields another <literal>NaN</literal>. When writing this value
as a constant in an SQL command, you must put quotes around it,
for example <literal>UPDATE table SET x = 'NaN'</literal>. On input,
the string <literal>NaN</literal> is recognized in a case-insensitive manner.
In addition to ordinary numeric values, the <type>numeric</type> type
has several special values:
<literallayout>
<literal>Infinity</literal>
<literal>-Infinity</literal>
<literal>NaN</literal>
</literallayout>
These are adapted from the IEEE 754 standard, and represent
<quote>infinity</quote>, <quote>negative infinity</quote>, and
<quote>not-a-number</quote>, respectively. When writing these values
as constants in an SQL command, you must put quotes around them,
for example <literal>UPDATE table SET x = '-Infinity'</literal>.
On input, these strings are recognized in a case-insensitive manner.
The infinity values can alternatively be spelled <literal>inf</literal>
and <literal>-inf</literal>.
</para>
<para>
The infinity values behave as per mathematical expectations. For
example, <literal>Infinity</literal> plus any finite value equals
<literal>Infinity</literal>, as does <literal>Infinity</literal>
plus <literal>Infinity</literal>; but <literal>Infinity</literal>
minus <literal>Infinity</literal> yields <literal>NaN</literal> (not a
number), because it has no well-defined interpretation. Note that an
infinity can only be stored in an unconstrained <type>numeric</type>
column, because it notionally exceeds any finite precision limit.
</para>
<para>
The <literal>NaN</literal> (not a number) value is used to represent
undefined calculational results. In general, any operation with
a <literal>NaN</literal> input yields another <literal>NaN</literal>.
The only exception is when the operation's other inputs are such that
the same output would be obtained if the <literal>NaN</literal> were to
be replaced by any finite or infinite numeric value; then, that output
value is used for <literal>NaN</literal> too. (An example of this
principle is that <literal>NaN</literal> raised to the zero power
yields one.)
</para>
<note>
@ -781,9 +817,14 @@ FROM generate_series(-3.5, 3.5, 1) as x;
</para>
</note>
<indexterm>
<primary>infinity</primary>
<secondary>floating point</secondary>
</indexterm>
<indexterm>
<primary>not a number</primary>
<secondary>double precision</secondary>
<secondary>floating point</secondary>
</indexterm>
<para>
@ -800,11 +841,13 @@ FROM generate_series(-3.5, 3.5, 1) as x;
as constants in an SQL command, you must put quotes around them,
for example <literal>UPDATE table SET x = '-Infinity'</literal>. On input,
these strings are recognized in a case-insensitive manner.
The infinity values can alternatively be spelled <literal>inf</literal>
and <literal>-inf</literal>.
</para>
<note>
<para>
IEEE754 specifies that <literal>NaN</literal> should not compare equal
IEEE 754 specifies that <literal>NaN</literal> should not compare equal
to any other floating-point value (including <literal>NaN</literal>).
In order to allow floating-point values to be sorted and used
in tree-based indexes, <productname>PostgreSQL</productname> treats

View File

@ -6129,9 +6129,12 @@ numeric_to_char(PG_FUNCTION_ARGS)
/*
* numeric_out_sci() does not emit a sign for positive numbers. We
* need to add a space in this case so that positive and negative
* numbers are aligned. We also have to do the right thing for NaN.
* numbers are aligned. Also must check for NaN/infinity cases, which
* we handle the same way as in float8_to_char.
*/
if (strcmp(orgnum, "NaN") == 0)
if (strcmp(orgnum, "NaN") == 0 ||
strcmp(orgnum, "Infinity") == 0 ||
strcmp(orgnum, "-Infinity") == 0)
{
/*
* Allow 6 characters for the leading sign, the decimal point,
@ -6346,7 +6349,7 @@ int8_to_char(PG_FUNCTION_ARGS)
/*
* numeric_out_sci() does not emit a sign for positive numbers. We
* need to add a space in this case so that positive and negative
* numbers are aligned. We don't have to worry about NaN here.
* numbers are aligned. We don't have to worry about NaN/inf here.
*/
if (*orgnum != '-')
{

File diff suppressed because it is too large Load Diff

View File

@ -57,6 +57,7 @@ typedef struct NumericData *Numeric;
* Utility functions in numeric.c
*/
extern bool numeric_is_nan(Numeric num);
extern bool numeric_is_inf(Numeric num);
int32 numeric_maximum_size(int32 typmod);
extern char *numeric_out_sci(Numeric num, int scale);
extern char *numeric_normalize(Numeric num);

View File

@ -211,6 +211,18 @@ SELECT stddev_pop(3.0::numeric), stddev_samp(4.0::numeric);
0 |
(1 row)
SELECT var_pop('inf'::numeric), var_samp('inf'::numeric);
var_pop | var_samp
---------+----------
NaN |
(1 row)
SELECT stddev_pop('inf'::numeric), stddev_samp('inf'::numeric);
stddev_pop | stddev_samp
------------+-------------
NaN |
(1 row)
SELECT var_pop('nan'::numeric), var_samp('nan'::numeric);
var_pop | var_samp
---------+----------
@ -285,32 +297,74 @@ select avg('NaN'::numeric) from generate_series(1,3);
(1 row)
-- verify correct results for infinite inputs
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('1'), ('infinity')) v(x);
avg | var_pop
----------+---------
Infinity | NaN
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('infinity'), ('1')) v(x);
avg | var_pop
----------+---------
Infinity | NaN
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('infinity'), ('infinity')) v(x);
avg | var_pop
----------+---------
Infinity | NaN
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('-infinity'), ('infinity')) v(x);
avg | var_pop
-----+---------
NaN | NaN
sum | avg | var_pop
-----+-----+---------
NaN | NaN | NaN
(1 row)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('-infinity'), ('-infinity')) v(x);
sum | avg | var_pop
-----------+-----------+---------
-Infinity | -Infinity | NaN
(1 row)
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('1'), ('infinity')) v(x);
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('infinity'), ('1')) v(x);
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('infinity'), ('infinity')) v(x);
sum | avg | var_pop
----------+----------+---------
Infinity | Infinity | NaN
(1 row)
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('-infinity'), ('infinity')) v(x);
sum | avg | var_pop
-----+-----+---------
NaN | NaN | NaN
(1 row)
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('-infinity'), ('-infinity')) v(x);
sum | avg | var_pop
-----------+-----------+---------
-Infinity | -Infinity | NaN
(1 row)
-- test accuracy with a large input offset

View File

@ -660,6 +660,432 @@ SELECT t1.id1, t1.result, t2.expected
-----+--------+----------
(0 rows)
-- ******************************
-- * Check behavior with Inf and NaN inputs. It's easiest to handle these
-- * separately from the num_data framework used above, because some input
-- * combinations will throw errors.
-- ******************************
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('inf'),('-inf'),('nan'))
SELECT x1, x2,
x1 + x2 AS sum,
x1 - x2 AS diff,
x1 * x2 AS prod
FROM v AS v1(x1), v AS v2(x2);
x1 | x2 | sum | diff | prod
-----------+-----------+-----------+-----------+-----------
0 | 0 | 0 | 0 | 0
0 | 1 | 1 | -1 | 0
0 | -1 | -1 | 1 | 0
0 | 4.2 | 4.2 | -4.2 | 0.0
0 | Infinity | Infinity | -Infinity | NaN
0 | -Infinity | -Infinity | Infinity | NaN
0 | NaN | NaN | NaN | NaN
1 | 0 | 1 | 1 | 0
1 | 1 | 2 | 0 | 1
1 | -1 | 0 | 2 | -1
1 | 4.2 | 5.2 | -3.2 | 4.2
1 | Infinity | Infinity | -Infinity | Infinity
1 | -Infinity | -Infinity | Infinity | -Infinity
1 | NaN | NaN | NaN | NaN
-1 | 0 | -1 | -1 | 0
-1 | 1 | 0 | -2 | -1
-1 | -1 | -2 | 0 | 1
-1 | 4.2 | 3.2 | -5.2 | -4.2
-1 | Infinity | Infinity | -Infinity | -Infinity
-1 | -Infinity | -Infinity | Infinity | Infinity
-1 | NaN | NaN | NaN | NaN
4.2 | 0 | 4.2 | 4.2 | 0.0
4.2 | 1 | 5.2 | 3.2 | 4.2
4.2 | -1 | 3.2 | 5.2 | -4.2
4.2 | 4.2 | 8.4 | 0.0 | 17.64
4.2 | Infinity | Infinity | -Infinity | Infinity
4.2 | -Infinity | -Infinity | Infinity | -Infinity
4.2 | NaN | NaN | NaN | NaN
Infinity | 0 | Infinity | Infinity | NaN
Infinity | 1 | Infinity | Infinity | Infinity
Infinity | -1 | Infinity | Infinity | -Infinity
Infinity | 4.2 | Infinity | Infinity | Infinity
Infinity | Infinity | Infinity | NaN | Infinity
Infinity | -Infinity | NaN | Infinity | -Infinity
Infinity | NaN | NaN | NaN | NaN
-Infinity | 0 | -Infinity | -Infinity | NaN
-Infinity | 1 | -Infinity | -Infinity | -Infinity
-Infinity | -1 | -Infinity | -Infinity | Infinity
-Infinity | 4.2 | -Infinity | -Infinity | -Infinity
-Infinity | Infinity | NaN | -Infinity | -Infinity
-Infinity | -Infinity | -Infinity | NaN | Infinity
-Infinity | NaN | NaN | NaN | NaN
NaN | 0 | NaN | NaN | NaN
NaN | 1 | NaN | NaN | NaN
NaN | -1 | NaN | NaN | NaN
NaN | 4.2 | NaN | NaN | NaN
NaN | Infinity | NaN | NaN | NaN
NaN | -Infinity | NaN | NaN | NaN
NaN | NaN | NaN | NaN | NaN
(49 rows)
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('inf'),('-inf'),('nan'))
SELECT x1, x2,
x1 / x2 AS quot,
x1 % x2 AS mod,
div(x1, x2) AS div
FROM v AS v1(x1), v AS v2(x2) WHERE x2 != 0;
x1 | x2 | quot | mod | div
-----------+-----------+-------------------------+------+-----------
0 | 1 | 0.00000000000000000000 | 0 | 0
1 | 1 | 1.00000000000000000000 | 0 | 1
-1 | 1 | -1.00000000000000000000 | 0 | -1
4.2 | 1 | 4.2000000000000000 | 0.2 | 4
Infinity | 1 | Infinity | NaN | Infinity
-Infinity | 1 | -Infinity | NaN | -Infinity
NaN | 1 | NaN | NaN | NaN
0 | -1 | 0.00000000000000000000 | 0 | 0
1 | -1 | -1.00000000000000000000 | 0 | -1
-1 | -1 | 1.00000000000000000000 | 0 | 1
4.2 | -1 | -4.2000000000000000 | 0.2 | -4
Infinity | -1 | -Infinity | NaN | -Infinity
-Infinity | -1 | Infinity | NaN | Infinity
NaN | -1 | NaN | NaN | NaN
0 | 4.2 | 0.00000000000000000000 | 0.0 | 0
1 | 4.2 | 0.23809523809523809524 | 1.0 | 0
-1 | 4.2 | -0.23809523809523809524 | -1.0 | 0
4.2 | 4.2 | 1.00000000000000000000 | 0.0 | 1
Infinity | 4.2 | Infinity | NaN | Infinity
-Infinity | 4.2 | -Infinity | NaN | -Infinity
NaN | 4.2 | NaN | NaN | NaN
0 | Infinity | 0 | 0 | 0
1 | Infinity | 0 | 1 | 0
-1 | Infinity | 0 | -1 | 0
4.2 | Infinity | 0 | 4.2 | 0
Infinity | Infinity | NaN | NaN | NaN
-Infinity | Infinity | NaN | NaN | NaN
NaN | Infinity | NaN | NaN | NaN
0 | -Infinity | 0 | 0 | 0
1 | -Infinity | 0 | 1 | 0
-1 | -Infinity | 0 | -1 | 0
4.2 | -Infinity | 0 | 4.2 | 0
Infinity | -Infinity | NaN | NaN | NaN
-Infinity | -Infinity | NaN | NaN | NaN
NaN | -Infinity | NaN | NaN | NaN
0 | NaN | NaN | NaN | NaN
1 | NaN | NaN | NaN | NaN
-1 | NaN | NaN | NaN | NaN
4.2 | NaN | NaN | NaN | NaN
Infinity | NaN | NaN | NaN | NaN
-Infinity | NaN | NaN | NaN | NaN
NaN | NaN | NaN | NaN | NaN
(42 rows)
SELECT 'inf'::numeric / '0';
ERROR: division by zero
SELECT '-inf'::numeric / '0';
ERROR: division by zero
SELECT 'nan'::numeric / '0';
?column?
----------
NaN
(1 row)
SELECT '0'::numeric / '0';
ERROR: division by zero
SELECT 'inf'::numeric % '0';
ERROR: division by zero
SELECT '-inf'::numeric % '0';
ERROR: division by zero
SELECT 'nan'::numeric % '0';
?column?
----------
NaN
(1 row)
SELECT '0'::numeric % '0';
ERROR: division by zero
SELECT div('inf'::numeric, '0');
ERROR: division by zero
SELECT div('-inf'::numeric, '0');
ERROR: division by zero
SELECT div('nan'::numeric, '0');
div
-----
NaN
(1 row)
SELECT div('0'::numeric, '0');
ERROR: division by zero
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('inf'),('-inf'),('nan'))
SELECT x, -x as minusx, abs(x), floor(x), ceil(x), sign(x), numeric_inc(x) as inc
FROM v;
x | minusx | abs | floor | ceil | sign | inc
-----------+-----------+----------+-----------+-----------+------+-----------
0 | 0 | 0 | 0 | 0 | 0 | 1
1 | -1 | 1 | 1 | 1 | 1 | 2
-1 | 1 | 1 | -1 | -1 | -1 | 0
4.2 | -4.2 | 4.2 | 4 | 5 | 1 | 5.2
-7.777 | 7.777 | 7.777 | -8 | -7 | -1 | -6.777
Infinity | -Infinity | Infinity | Infinity | Infinity | 1 | Infinity
-Infinity | Infinity | Infinity | -Infinity | -Infinity | -1 | -Infinity
NaN | NaN | NaN | NaN | NaN | NaN | NaN
(8 rows)
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('inf'),('-inf'),('nan'))
SELECT x, round(x), round(x,1) as round1, trunc(x), trunc(x,1) as trunc1
FROM v;
x | round | round1 | trunc | trunc1
-----------+-----------+-----------+-----------+-----------
0 | 0 | 0.0 | 0 | 0.0
1 | 1 | 1.0 | 1 | 1.0
-1 | -1 | -1.0 | -1 | -1.0
4.2 | 4 | 4.2 | 4 | 4.2
-7.777 | -8 | -7.8 | -7 | -7.7
Infinity | Infinity | Infinity | Infinity | Infinity
-Infinity | -Infinity | -Infinity | -Infinity | -Infinity
NaN | NaN | NaN | NaN | NaN
(8 rows)
-- the large values fall into the numeric abbreviation code's maximal classes
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('1e340'),('-1e340'),
('inf'),('-inf'),('nan'),
('inf'),('-inf'),('nan'))
SELECT substring(x::text, 1, 32)
FROM v ORDER BY x;
substring
----------------------------------
-Infinity
-Infinity
-1000000000000000000000000000000
-7.777
-1
0
1
4.2
10000000000000000000000000000000
Infinity
Infinity
NaN
NaN
(13 rows)
WITH v(x) AS
(VALUES('0'::numeric),('1'),('4.2'),('inf'),('nan'))
SELECT x, sqrt(x)
FROM v;
x | sqrt
----------+-------------------
0 | 0.000000000000000
1 | 1.000000000000000
4.2 | 2.049390153191920
Infinity | Infinity
NaN | NaN
(5 rows)
SELECT sqrt('-1'::numeric);
ERROR: cannot take square root of a negative number
SELECT sqrt('-inf'::numeric);
ERROR: cannot take square root of a negative number
WITH v(x) AS
(VALUES('1'::numeric),('4.2'),('inf'),('nan'))
SELECT x,
log(x),
log10(x),
ln(x)
FROM v;
x | log | log10 | ln
----------+--------------------+--------------------+--------------------
1 | 0.0000000000000000 | 0.0000000000000000 | 0.0000000000000000
4.2 | 0.6232492903979005 | 0.6232492903979005 | 1.4350845252893226
Infinity | Infinity | Infinity | Infinity
NaN | NaN | NaN | NaN
(4 rows)
SELECT ln('0'::numeric);
ERROR: cannot take logarithm of zero
SELECT ln('-1'::numeric);
ERROR: cannot take logarithm of a negative number
SELECT ln('-inf'::numeric);
ERROR: cannot take logarithm of a negative number
WITH v(x) AS
(VALUES('2'::numeric),('4.2'),('inf'),('nan'))
SELECT x1, x2,
log(x1, x2)
FROM v AS v1(x1), v AS v2(x2);
x1 | x2 | log
----------+----------+--------------------
2 | 2 | 1.0000000000000000
2 | 4.2 | 2.0703893278913979
2 | Infinity | Infinity
2 | NaN | NaN
4.2 | 2 | 0.4830009440873890
4.2 | 4.2 | 1.0000000000000000
4.2 | Infinity | Infinity
4.2 | NaN | NaN
Infinity | 2 | 0
Infinity | 4.2 | 0
Infinity | Infinity | NaN
Infinity | NaN | NaN
NaN | 2 | NaN
NaN | 4.2 | NaN
NaN | Infinity | NaN
NaN | NaN | NaN
(16 rows)
SELECT log('0'::numeric, '10');
ERROR: cannot take logarithm of zero
SELECT log('10'::numeric, '0');
ERROR: cannot take logarithm of zero
SELECT log('-inf'::numeric, '10');
ERROR: cannot take logarithm of a negative number
SELECT log('10'::numeric, '-inf');
ERROR: cannot take logarithm of a negative number
SELECT log('inf'::numeric, '0');
ERROR: cannot take logarithm of zero
SELECT log('inf'::numeric, '-inf');
ERROR: cannot take logarithm of a negative number
SELECT log('-inf'::numeric, 'inf');
ERROR: cannot take logarithm of a negative number
WITH v(x) AS
(VALUES('0'::numeric),('1'),('2'),('4.2'),('inf'),('nan'))
SELECT x1, x2,
power(x1, x2)
FROM v AS v1(x1), v AS v2(x2) WHERE x1 != 0 OR x2 >= 0;
x1 | x2 | power
----------+----------+---------------------
0 | 0 | 1.0000000000000000
0 | 1 | 0.0000000000000000
0 | 2 | 0.0000000000000000
0 | 4.2 | 0.0000000000000000
0 | Infinity | 0
0 | NaN | NaN
1 | 0 | 1.0000000000000000
1 | 1 | 1.0000000000000000
1 | 2 | 1.0000000000000000
1 | 4.2 | 1.0000000000000000
1 | Infinity | 1
1 | NaN | 1
2 | 0 | 1.0000000000000000
2 | 1 | 2.0000000000000000
2 | 2 | 4.0000000000000000
2 | 4.2 | 18.379173679952560
2 | Infinity | Infinity
2 | NaN | NaN
4.2 | 0 | 1.0000000000000000
4.2 | 1 | 4.2000000000000000
4.2 | 2 | 17.6400000000000000
4.2 | 4.2 | 414.61691860129675
4.2 | Infinity | Infinity
4.2 | NaN | NaN
Infinity | 0 | 1
Infinity | 1 | Infinity
Infinity | 2 | Infinity
Infinity | 4.2 | Infinity
Infinity | Infinity | Infinity
Infinity | NaN | NaN
NaN | 0 | 1
NaN | 1 | NaN
NaN | 2 | NaN
NaN | 4.2 | NaN
NaN | Infinity | NaN
NaN | NaN | NaN
(36 rows)
SELECT power('0'::numeric, '-1');
ERROR: zero raised to a negative power is undefined
SELECT power('0'::numeric, '-inf');
ERROR: zero raised to a negative power is undefined
SELECT power('-1'::numeric, 'inf');
power
-------
1
(1 row)
SELECT power('-2'::numeric, '3');
power
---------------------
-8.0000000000000000
(1 row)
SELECT power('-2'::numeric, '3.3');
ERROR: a negative number raised to a non-integer power yields a complex result
SELECT power('-2'::numeric, '-1');
power
---------------------
-0.5000000000000000
(1 row)
SELECT power('-2'::numeric, '-1.5');
ERROR: a negative number raised to a non-integer power yields a complex result
SELECT power('-2'::numeric, 'inf');
power
----------
Infinity
(1 row)
SELECT power('-2'::numeric, '-inf');
power
-------
0
(1 row)
SELECT power('inf'::numeric, '-2');
power
-------
0
(1 row)
SELECT power('inf'::numeric, '-inf');
power
-------
0
(1 row)
SELECT power('-inf'::numeric, '2');
power
----------
Infinity
(1 row)
SELECT power('-inf'::numeric, '3');
power
-----------
-Infinity
(1 row)
SELECT power('-inf'::numeric, '4.5');
ERROR: a negative number raised to a non-integer power yields a complex result
SELECT power('-inf'::numeric, '-2');
power
-------
0
(1 row)
SELECT power('-inf'::numeric, '-3');
power
-------
0
(1 row)
SELECT power('-inf'::numeric, '0');
power
-------
1
(1 row)
SELECT power('-inf'::numeric, 'inf');
power
----------
Infinity
(1 row)
SELECT power('-inf'::numeric, '-inf');
power
-------
0
(1 row)
-- ******************************
-- * miscellaneous checks for things that have been broken in the past...
-- ******************************
@ -696,6 +1122,13 @@ ERROR: numeric field overflow
DETAIL: A field with precision 4, scale 4 must round to an absolute value less than 1.
INSERT INTO fract_only VALUES (7, '0.00001');
INSERT INTO fract_only VALUES (8, '0.00017');
INSERT INTO fract_only VALUES (9, 'NaN');
INSERT INTO fract_only VALUES (10, 'Inf'); -- should fail
ERROR: numeric field overflow
DETAIL: A field with precision 4, scale 4 cannot hold an infinite value.
INSERT INTO fract_only VALUES (11, '-Inf'); -- should fail
ERROR: numeric field overflow
DETAIL: A field with precision 4, scale 4 cannot hold an infinite value.
SELECT * FROM fract_only;
id | val
----+---------
@ -705,7 +1138,8 @@ SELECT * FROM fract_only;
5 | 0.9999
7 | 0.0000
8 | 0.0002
(6 rows)
9 | NaN
(7 rows)
DROP TABLE fract_only;
-- Check inf/nan conversion behavior
@ -716,9 +1150,35 @@ SELECT 'NaN'::float8::numeric;
(1 row)
SELECT 'Infinity'::float8::numeric;
ERROR: cannot convert infinity to numeric
numeric
----------
Infinity
(1 row)
SELECT '-Infinity'::float8::numeric;
ERROR: cannot convert infinity to numeric
numeric
-----------
-Infinity
(1 row)
SELECT 'NaN'::numeric::float8;
float8
--------
NaN
(1 row)
SELECT 'Infinity'::numeric::float8;
float8
----------
Infinity
(1 row)
SELECT '-Infinity'::numeric::float8;
float8
-----------
-Infinity
(1 row)
SELECT 'NaN'::float4::numeric;
numeric
---------
@ -726,9 +1186,59 @@ SELECT 'NaN'::float4::numeric;
(1 row)
SELECT 'Infinity'::float4::numeric;
ERROR: cannot convert infinity to numeric
numeric
----------
Infinity
(1 row)
SELECT '-Infinity'::float4::numeric;
ERROR: cannot convert infinity to numeric
numeric
-----------
-Infinity
(1 row)
SELECT 'NaN'::numeric::float4;
float4
--------
NaN
(1 row)
SELECT 'Infinity'::numeric::float4;
float4
----------
Infinity
(1 row)
SELECT '-Infinity'::numeric::float4;
float4
-----------
-Infinity
(1 row)
SELECT '42'::int2::numeric;
numeric
---------
42
(1 row)
SELECT 'NaN'::numeric::int2;
ERROR: cannot convert NaN to smallint
SELECT 'Infinity'::numeric::int2;
ERROR: cannot convert infinity to smallint
SELECT '-Infinity'::numeric::int2;
ERROR: cannot convert infinity to smallint
SELECT 'NaN'::numeric::int4;
ERROR: cannot convert NaN to integer
SELECT 'Infinity'::numeric::int4;
ERROR: cannot convert infinity to integer
SELECT '-Infinity'::numeric::int4;
ERROR: cannot convert infinity to integer
SELECT 'NaN'::numeric::int8;
ERROR: cannot convert NaN to bigint
SELECT 'Infinity'::numeric::int8;
ERROR: cannot convert infinity to bigint
SELECT '-Infinity'::numeric::int8;
ERROR: cannot convert infinity to bigint
-- Simple check that ceil(), floor(), and round() work correctly
CREATE TABLE ceil_floor_round (a numeric);
INSERT INTO ceil_floor_round VALUES ('-5.5');
@ -794,6 +1304,12 @@ SELECT width_bucket('NaN', 3.0, 4.0, 888);
ERROR: operand, lower bound, and upper bound cannot be NaN
SELECT width_bucket(0::float8, 'NaN', 4.0::float8, 888);
ERROR: operand, lower bound, and upper bound cannot be NaN
SELECT width_bucket('inf', 3.0, 4.0, 888);
ERROR: operand, lower bound, and upper bound cannot be infinity
SELECT width_bucket(2.0, 3.0, '-inf', 888);
ERROR: operand, lower bound, and upper bound cannot be infinity
SELECT width_bucket(0::float8, '-inf', 4.0::float8, 888);
ERROR: lower and upper bounds must be finite
-- normal operation
CREATE TABLE width_bucket_test (operand_num numeric, operand_f8 float8);
COPY width_bucket_test (operand_num) FROM stdin;
@ -1199,6 +1715,60 @@ SELECT '' AS to_char_23, to_char(val, '9.999EEEE') FROM num_data;
| -2.493e+07
(10 rows)
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, '9.999EEEE') as numeric,
to_char(val::float8, '9.999EEEE') as float8,
to_char(val::float4, '9.999EEEE') as float4
FROM v;
val | numeric | float8 | float4
------------+------------+------------+------------
0 | 0.000e+00 | 0.000e+00 | 0.000e+00
-4.2 | -4.200e+00 | -4.200e+00 | -4.200e+00
4200000000 | 4.200e+09 | 4.200e+09 | 4.200e+09
0.000012 | 1.200e-05 | 1.200e-05 | 1.200e-05
Infinity | #.####### | #.####### | #.#######
-Infinity | #.####### | #.####### | #.#######
NaN | #.####### | #.####### | #.#######
(7 rows)
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, 'MI9999999999.99') as numeric,
to_char(val::float8, 'MI9999999999.99') as float8,
to_char(val::float4, 'MI9999999999.99') as float4
FROM v;
val | numeric | float8 | float4
------------+----------------+----------------+----------------
0 | .00 | .00 | .00
-4.2 | - 4.20 | - 4.20 | - 4.20
4200000000 | 4200000000.00 | 4200000000.00 | 4200000000
0.000012 | .00 | .00 | .00
Infinity | Infinity | Infinity | Infinity
-Infinity | - Infinity | - Infinity | - Infinity
NaN | NaN | NaN | NaN
(7 rows)
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, 'MI99.99') as numeric,
to_char(val::float8, 'MI99.99') as float8,
to_char(val::float4, 'MI99.99') as float4
FROM v;
val | numeric | float8 | float4
------------+---------+--------+--------
0 | .00 | .00 | .00
-4.2 | - 4.20 | - 4.20 | - 4.20
4200000000 | ##.## | ##.## | ##.
0.000012 | .00 | .00 | .00
Infinity | ##.## | ##.## | ##.
-Infinity | -##.## | -##.## | -##.
NaN | ##.## | ##.## | ##.##
(7 rows)
SELECT '' AS to_char_24, to_char('100'::numeric, 'FM999.9');
to_char_24 | to_char
------------+---------
@ -1426,6 +1996,12 @@ INSERT INTO num_input_test(n1) VALUES ('555.50');
INSERT INTO num_input_test(n1) VALUES ('-555.50');
INSERT INTO num_input_test(n1) VALUES ('NaN ');
INSERT INTO num_input_test(n1) VALUES (' nan');
INSERT INTO num_input_test(n1) VALUES (' inf ');
INSERT INTO num_input_test(n1) VALUES (' +inf ');
INSERT INTO num_input_test(n1) VALUES (' -inf ');
INSERT INTO num_input_test(n1) VALUES (' Infinity ');
INSERT INTO num_input_test(n1) VALUES (' +inFinity ');
INSERT INTO num_input_test(n1) VALUES (' -INFINITY ');
-- bad inputs
INSERT INTO num_input_test(n1) VALUES (' ');
ERROR: invalid input syntax for type numeric: " "
@ -1459,17 +2035,27 @@ INSERT INTO num_input_test(n1) VALUES (' N aN ');
ERROR: invalid input syntax for type numeric: " N aN "
LINE 1: INSERT INTO num_input_test(n1) VALUES (' N aN ');
^
INSERT INTO num_input_test(n1) VALUES ('+ infinity');
ERROR: invalid input syntax for type numeric: "+ infinity"
LINE 1: INSERT INTO num_input_test(n1) VALUES ('+ infinity');
^
SELECT * FROM num_input_test;
n1
---------
123
3245874
-93853
555.50
-555.50
NaN
NaN
(7 rows)
n1
-----------
123
3245874
-93853
555.50
-555.50
NaN
NaN
Infinity
Infinity
-Infinity
Infinity
Infinity
-Infinity
(13 rows)
--
-- Test some corner cases for multiplication
@ -1805,6 +2391,24 @@ select exp(1.0::numeric(71,70));
2.7182818284590452353602874713526624977572470936999595749669676277240766
(1 row)
select exp('nan'::numeric);
exp
-----
NaN
(1 row)
select exp('inf'::numeric);
exp
----------
Infinity
(1 row)
select exp('-inf'::numeric);
exp
-----
0
(1 row)
-- cases that used to generate inaccurate results
select exp(32.999);
exp
@ -1876,6 +2480,12 @@ select * from generate_series('nan'::numeric, 100::numeric, 10::numeric);
ERROR: start value cannot be NaN
select * from generate_series(0::numeric, 'nan'::numeric, 10::numeric);
ERROR: stop value cannot be NaN
select * from generate_series('inf'::numeric, 'inf'::numeric, 10::numeric);
ERROR: start value cannot be infinity
select * from generate_series(0::numeric, 'inf'::numeric, 10::numeric);
ERROR: stop value cannot be infinity
select * from generate_series(0::numeric, '42'::numeric, '-inf'::numeric);
ERROR: step size cannot be infinity
-- Checks maximum, output is truncated
select (i / (10::numeric ^ 131071))::numeric(1,0)
from generate_series(6 * (10::numeric ^ 131071),
@ -2081,6 +2691,12 @@ select scale(numeric 'NaN');
(1 row)
select scale(numeric 'inf');
scale
-------
(1 row)
select scale(NULL::numeric);
scale
-------
@ -2138,6 +2754,12 @@ select min_scale(numeric 'NaN') is NULL; -- should be true
t
(1 row)
select min_scale(numeric 'inf') is NULL; -- should be true
?column?
----------
t
(1 row)
select min_scale(0); -- no digits
min_scale
-----------
@ -2207,6 +2829,12 @@ select trim_scale(numeric 'NaN');
NaN
(1 row)
select trim_scale(numeric 'inf');
trim_scale
------------
Infinity
(1 row)
select trim_scale(1.120);
trim_scale
------------
@ -2280,7 +2908,11 @@ FROM (VALUES (0::numeric, 0::numeric),
(0::numeric, 46375::numeric),
(433125::numeric, 46375::numeric),
(43312.5::numeric, 4637.5::numeric),
(4331.250::numeric, 463.75000::numeric)) AS v(a, b);
(4331.250::numeric, 463.75000::numeric),
('inf', '0'),
('inf', '42'),
('inf', 'inf')
) AS v(a, b);
a | b | gcd | gcd | gcd | gcd
----------+-----------+---------+---------+---------+---------
0 | 0 | 0 | 0 | 0 | 0
@ -2289,7 +2921,10 @@ FROM (VALUES (0::numeric, 0::numeric),
433125 | 46375 | 875 | 875 | 875 | 875
43312.5 | 4637.5 | 87.5 | 87.5 | 87.5 | 87.5
4331.250 | 463.75000 | 8.75000 | 8.75000 | 8.75000 | 8.75000
(6 rows)
Infinity | 0 | NaN | NaN | NaN | NaN
Infinity | 42 | NaN | NaN | NaN | NaN
Infinity | Infinity | NaN | NaN | NaN | NaN
(9 rows)
--
-- Tests for LCM()
@ -2301,7 +2936,11 @@ FROM (VALUES (0::numeric, 0::numeric),
(13272::numeric, 13272::numeric),
(423282::numeric, 13272::numeric),
(42328.2::numeric, 1327.2::numeric),
(4232.820::numeric, 132.72000::numeric)) AS v(a, b);
(4232.820::numeric, 132.72000::numeric),
('inf', '0'),
('inf', '42'),
('inf', 'inf')
) AS v(a, b);
a | b | lcm | lcm | lcm | lcm
----------+-----------+--------------+--------------+--------------+--------------
0 | 0 | 0 | 0 | 0 | 0
@ -2311,7 +2950,10 @@ FROM (VALUES (0::numeric, 0::numeric),
423282 | 13272 | 11851896 | 11851896 | 11851896 | 11851896
42328.2 | 1327.2 | 1185189.6 | 1185189.6 | 1185189.6 | 1185189.6
4232.820 | 132.72000 | 118518.96000 | 118518.96000 | 118518.96000 | 118518.96000
(7 rows)
Infinity | 0 | NaN | NaN | NaN | NaN
Infinity | 42 | NaN | NaN | NaN | NaN
Infinity | Infinity | NaN | NaN | NaN | NaN
(10 rows)
SELECT lcm(9999 * (10::numeric)^131068 + (10::numeric^131068 - 1), 2); -- overflow
ERROR: value overflows numeric format

View File

@ -1872,7 +1872,7 @@ create temp table numerics(
f_numeric numeric
);
insert into numerics values
(0, '-infinity', '-infinity', '-1000'), -- numeric type lacks infinities
(0, '-infinity', '-infinity', '-infinity'),
(1, -3, -3, -3),
(2, -1, -1, -1),
(3, 0, 0, 0),
@ -1880,7 +1880,7 @@ insert into numerics values
(5, 1.12, 1.12, 1.12),
(6, 2, 2, 2),
(7, 100, 100, 100),
(8, 'infinity', 'infinity', '1000'),
(8, 'infinity', 'infinity', 'infinity'),
(9, 'NaN', 'NaN', 'NaN');
select id, f_float4, first_value(id) over w, last_value(id) over w
from numerics
@ -2078,7 +2078,7 @@ window w as (order by f_numeric range between
1 preceding and 1 following);
id | f_numeric | first_value | last_value
----+-----------+-------------+------------
0 | -1000 | 0 | 0
0 | -Infinity | 0 | 0
1 | -3 | 1 | 1
2 | -1 | 2 | 3
3 | 0 | 2 | 3
@ -2086,7 +2086,7 @@ window w as (order by f_numeric range between
5 | 1.12 | 4 | 6
6 | 2 | 4 | 6
7 | 100 | 7 | 7
8 | 1000 | 8 | 8
8 | Infinity | 8 | 8
9 | NaN | 9 | 9
(10 rows)
@ -2096,7 +2096,7 @@ window w as (order by f_numeric range between
1 preceding and 1.1::numeric following);
id | f_numeric | first_value | last_value
----+-----------+-------------+------------
0 | -1000 | 0 | 0
0 | -Infinity | 0 | 0
1 | -3 | 1 | 1
2 | -1 | 2 | 3
3 | 0 | 2 | 4
@ -2104,7 +2104,7 @@ window w as (order by f_numeric range between
5 | 1.12 | 4 | 6
6 | 2 | 4 | 6
7 | 100 | 7 | 7
8 | 1000 | 8 | 8
8 | Infinity | 8 | 8
9 | NaN | 9 | 9
(10 rows)
@ -2116,6 +2116,60 @@ ERROR: RANGE with offset PRECEDING/FOLLOWING is not supported for column type n
LINE 4: 1 preceding and 1.1::float8 following);
^
HINT: Cast the offset value to an appropriate type.
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' preceding and 'inf' following);
id | f_numeric | first_value | last_value
----+-----------+-------------+------------
0 | -Infinity | 0 | 8
1 | -3 | 0 | 8
2 | -1 | 0 | 8
3 | 0 | 0 | 8
4 | 1.1 | 0 | 8
5 | 1.12 | 0 | 8
6 | 2 | 0 | 8
7 | 100 | 0 | 8
8 | Infinity | 0 | 8
9 | NaN | 9 | 9
(10 rows)
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' preceding and 'inf' preceding);
id | f_numeric | first_value | last_value
----+-----------+-------------+------------
0 | -Infinity | 0 | 0
1 | -3 | 0 | 0
2 | -1 | 0 | 0
3 | 0 | 0 | 0
4 | 1.1 | 0 | 0
5 | 1.12 | 0 | 0
6 | 2 | 0 | 0
7 | 100 | 0 | 0
8 | Infinity | 0 | 8
9 | NaN | 9 | 9
(10 rows)
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' following and 'inf' following);
id | f_numeric | first_value | last_value
----+-----------+-------------+------------
0 | -Infinity | 0 | 8
1 | -3 | 8 | 8
2 | -1 | 8 | 8
3 | 0 | 8 | 8
4 | 1.1 | 8 | 8
5 | 1.12 | 8 | 8
6 | 2 | 8 | 8
7 | 100 | 8 | 8
8 | Infinity | 8 | 8
9 | NaN | 9 | 9
(10 rows)
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between

View File

@ -53,6 +53,8 @@ SELECT var_pop('nan'::float4), var_samp('nan'::float4);
SELECT stddev_pop('nan'::float4), stddev_samp('nan'::float4);
SELECT var_pop(1.0::numeric), var_samp(2.0::numeric);
SELECT stddev_pop(3.0::numeric), stddev_samp(4.0::numeric);
SELECT var_pop('inf'::numeric), var_samp('inf'::numeric);
SELECT stddev_pop('inf'::numeric), stddev_samp('inf'::numeric);
SELECT var_pop('nan'::numeric), var_samp('nan'::numeric);
SELECT stddev_pop('nan'::numeric), stddev_samp('nan'::numeric);
@ -69,14 +71,26 @@ select sum('NaN'::numeric) from generate_series(1,3);
select avg('NaN'::numeric) from generate_series(1,3);
-- verify correct results for infinite inputs
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('1'), ('infinity')) v(x);
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('infinity'), ('1')) v(x);
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('infinity'), ('infinity')) v(x);
SELECT avg(x::float8), var_pop(x::float8)
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('-infinity'), ('infinity')) v(x);
SELECT sum(x::float8), avg(x::float8), var_pop(x::float8)
FROM (VALUES ('-infinity'), ('-infinity')) v(x);
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('1'), ('infinity')) v(x);
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('infinity'), ('1')) v(x);
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('infinity'), ('infinity')) v(x);
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('-infinity'), ('infinity')) v(x);
SELECT sum(x::numeric), avg(x::numeric), var_pop(x::numeric)
FROM (VALUES ('-infinity'), ('-infinity')) v(x);
-- test accuracy with a large input offset
SELECT avg(x::float8), var_pop(x::float8)

View File

@ -634,6 +634,119 @@ SELECT t1.id1, t1.result, t2.expected
WHERE t1.id1 = t2.id
AND t1.result != t2.expected;
-- ******************************
-- * Check behavior with Inf and NaN inputs. It's easiest to handle these
-- * separately from the num_data framework used above, because some input
-- * combinations will throw errors.
-- ******************************
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('inf'),('-inf'),('nan'))
SELECT x1, x2,
x1 + x2 AS sum,
x1 - x2 AS diff,
x1 * x2 AS prod
FROM v AS v1(x1), v AS v2(x2);
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('inf'),('-inf'),('nan'))
SELECT x1, x2,
x1 / x2 AS quot,
x1 % x2 AS mod,
div(x1, x2) AS div
FROM v AS v1(x1), v AS v2(x2) WHERE x2 != 0;
SELECT 'inf'::numeric / '0';
SELECT '-inf'::numeric / '0';
SELECT 'nan'::numeric / '0';
SELECT '0'::numeric / '0';
SELECT 'inf'::numeric % '0';
SELECT '-inf'::numeric % '0';
SELECT 'nan'::numeric % '0';
SELECT '0'::numeric % '0';
SELECT div('inf'::numeric, '0');
SELECT div('-inf'::numeric, '0');
SELECT div('nan'::numeric, '0');
SELECT div('0'::numeric, '0');
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('inf'),('-inf'),('nan'))
SELECT x, -x as minusx, abs(x), floor(x), ceil(x), sign(x), numeric_inc(x) as inc
FROM v;
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('inf'),('-inf'),('nan'))
SELECT x, round(x), round(x,1) as round1, trunc(x), trunc(x,1) as trunc1
FROM v;
-- the large values fall into the numeric abbreviation code's maximal classes
WITH v(x) AS
(VALUES('0'::numeric),('1'),('-1'),('4.2'),('-7.777'),('1e340'),('-1e340'),
('inf'),('-inf'),('nan'),
('inf'),('-inf'),('nan'))
SELECT substring(x::text, 1, 32)
FROM v ORDER BY x;
WITH v(x) AS
(VALUES('0'::numeric),('1'),('4.2'),('inf'),('nan'))
SELECT x, sqrt(x)
FROM v;
SELECT sqrt('-1'::numeric);
SELECT sqrt('-inf'::numeric);
WITH v(x) AS
(VALUES('1'::numeric),('4.2'),('inf'),('nan'))
SELECT x,
log(x),
log10(x),
ln(x)
FROM v;
SELECT ln('0'::numeric);
SELECT ln('-1'::numeric);
SELECT ln('-inf'::numeric);
WITH v(x) AS
(VALUES('2'::numeric),('4.2'),('inf'),('nan'))
SELECT x1, x2,
log(x1, x2)
FROM v AS v1(x1), v AS v2(x2);
SELECT log('0'::numeric, '10');
SELECT log('10'::numeric, '0');
SELECT log('-inf'::numeric, '10');
SELECT log('10'::numeric, '-inf');
SELECT log('inf'::numeric, '0');
SELECT log('inf'::numeric, '-inf');
SELECT log('-inf'::numeric, 'inf');
WITH v(x) AS
(VALUES('0'::numeric),('1'),('2'),('4.2'),('inf'),('nan'))
SELECT x1, x2,
power(x1, x2)
FROM v AS v1(x1), v AS v2(x2) WHERE x1 != 0 OR x2 >= 0;
SELECT power('0'::numeric, '-1');
SELECT power('0'::numeric, '-inf');
SELECT power('-1'::numeric, 'inf');
SELECT power('-2'::numeric, '3');
SELECT power('-2'::numeric, '3.3');
SELECT power('-2'::numeric, '-1');
SELECT power('-2'::numeric, '-1.5');
SELECT power('-2'::numeric, 'inf');
SELECT power('-2'::numeric, '-inf');
SELECT power('inf'::numeric, '-2');
SELECT power('inf'::numeric, '-inf');
SELECT power('-inf'::numeric, '2');
SELECT power('-inf'::numeric, '3');
SELECT power('-inf'::numeric, '4.5');
SELECT power('-inf'::numeric, '-2');
SELECT power('-inf'::numeric, '-3');
SELECT power('-inf'::numeric, '0');
SELECT power('-inf'::numeric, 'inf');
SELECT power('-inf'::numeric, '-inf');
-- ******************************
-- * miscellaneous checks for things that have been broken in the past...
-- ******************************
@ -652,6 +765,9 @@ INSERT INTO fract_only VALUES (5, '0.99994');
INSERT INTO fract_only VALUES (6, '0.99995'); -- should fail
INSERT INTO fract_only VALUES (7, '0.00001');
INSERT INTO fract_only VALUES (8, '0.00017');
INSERT INTO fract_only VALUES (9, 'NaN');
INSERT INTO fract_only VALUES (10, 'Inf'); -- should fail
INSERT INTO fract_only VALUES (11, '-Inf'); -- should fail
SELECT * FROM fract_only;
DROP TABLE fract_only;
@ -659,9 +775,25 @@ DROP TABLE fract_only;
SELECT 'NaN'::float8::numeric;
SELECT 'Infinity'::float8::numeric;
SELECT '-Infinity'::float8::numeric;
SELECT 'NaN'::numeric::float8;
SELECT 'Infinity'::numeric::float8;
SELECT '-Infinity'::numeric::float8;
SELECT 'NaN'::float4::numeric;
SELECT 'Infinity'::float4::numeric;
SELECT '-Infinity'::float4::numeric;
SELECT 'NaN'::numeric::float4;
SELECT 'Infinity'::numeric::float4;
SELECT '-Infinity'::numeric::float4;
SELECT '42'::int2::numeric;
SELECT 'NaN'::numeric::int2;
SELECT 'Infinity'::numeric::int2;
SELECT '-Infinity'::numeric::int2;
SELECT 'NaN'::numeric::int4;
SELECT 'Infinity'::numeric::int4;
SELECT '-Infinity'::numeric::int4;
SELECT 'NaN'::numeric::int8;
SELECT 'Infinity'::numeric::int8;
SELECT '-Infinity'::numeric::int8;
-- Simple check that ceil(), floor(), and round() work correctly
CREATE TABLE ceil_floor_round (a numeric);
@ -697,6 +829,9 @@ SELECT width_bucket(5.0::float8, 3.0::float8, 4.0::float8, -5);
SELECT width_bucket(3.5::float8, 3.0::float8, 3.0::float8, 888);
SELECT width_bucket('NaN', 3.0, 4.0, 888);
SELECT width_bucket(0::float8, 'NaN', 4.0::float8, 888);
SELECT width_bucket('inf', 3.0, 4.0, 888);
SELECT width_bucket(2.0, 3.0, '-inf', 888);
SELECT width_bucket(0::float8, '-inf', 4.0::float8, 888);
-- normal operation
CREATE TABLE width_bucket_test (operand_num numeric, operand_f8 float8);
@ -782,6 +917,30 @@ SELECT '' AS to_char_21, to_char(val, '999999SG9999999999') FROM num_data;
SELECT '' AS to_char_22, to_char(val, 'FM9999999999999999.999999999999999') FROM num_data;
SELECT '' AS to_char_23, to_char(val, '9.999EEEE') FROM num_data;
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, '9.999EEEE') as numeric,
to_char(val::float8, '9.999EEEE') as float8,
to_char(val::float4, '9.999EEEE') as float4
FROM v;
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, 'MI9999999999.99') as numeric,
to_char(val::float8, 'MI9999999999.99') as float8,
to_char(val::float4, 'MI9999999999.99') as float4
FROM v;
WITH v(val) AS
(VALUES('0'::numeric),('-4.2'),('4.2e9'),('1.2e-5'),('inf'),('-inf'),('nan'))
SELECT val,
to_char(val, 'MI99.99') as numeric,
to_char(val::float8, 'MI99.99') as float8,
to_char(val::float4, 'MI99.99') as float4
FROM v;
SELECT '' AS to_char_24, to_char('100'::numeric, 'FM999.9');
SELECT '' AS to_char_25, to_char('100'::numeric, 'FM999.');
SELECT '' AS to_char_26, to_char('100'::numeric, 'FM999');
@ -839,6 +998,12 @@ INSERT INTO num_input_test(n1) VALUES ('555.50');
INSERT INTO num_input_test(n1) VALUES ('-555.50');
INSERT INTO num_input_test(n1) VALUES ('NaN ');
INSERT INTO num_input_test(n1) VALUES (' nan');
INSERT INTO num_input_test(n1) VALUES (' inf ');
INSERT INTO num_input_test(n1) VALUES (' +inf ');
INSERT INTO num_input_test(n1) VALUES (' -inf ');
INSERT INTO num_input_test(n1) VALUES (' Infinity ');
INSERT INTO num_input_test(n1) VALUES (' +inFinity ');
INSERT INTO num_input_test(n1) VALUES (' -INFINITY ');
-- bad inputs
INSERT INTO num_input_test(n1) VALUES (' ');
@ -849,6 +1014,7 @@ INSERT INTO num_input_test(n1) VALUES ('5 . 0');
INSERT INTO num_input_test(n1) VALUES ('5. 0 ');
INSERT INTO num_input_test(n1) VALUES ('');
INSERT INTO num_input_test(n1) VALUES (' N aN ');
INSERT INTO num_input_test(n1) VALUES ('+ infinity');
SELECT * FROM num_input_test;
@ -952,6 +1118,9 @@ select 1.234 ^ 5678;
select exp(0.0);
select exp(1.0);
select exp(1.0::numeric(71,70));
select exp('nan'::numeric);
select exp('inf'::numeric);
select exp('-inf'::numeric);
-- cases that used to generate inaccurate results
select exp(32.999);
@ -973,6 +1142,9 @@ select * from generate_series(-100::numeric, 100::numeric, 0::numeric);
select * from generate_series(-100::numeric, 100::numeric, 'nan'::numeric);
select * from generate_series('nan'::numeric, 100::numeric, 10::numeric);
select * from generate_series(0::numeric, 'nan'::numeric, 10::numeric);
select * from generate_series('inf'::numeric, 'inf'::numeric, 10::numeric);
select * from generate_series(0::numeric, 'inf'::numeric, 10::numeric);
select * from generate_series(0::numeric, '42'::numeric, '-inf'::numeric);
-- Checks maximum, output is truncated
select (i / (10::numeric ^ 131071))::numeric(1,0)
from generate_series(6 * (10::numeric ^ 131071),
@ -1040,6 +1212,7 @@ select log(3.1954752e47, 9.4792021e-73);
--
select scale(numeric 'NaN');
select scale(numeric 'inf');
select scale(NULL::numeric);
select scale(1.12);
select scale(0);
@ -1054,6 +1227,7 @@ select scale(-13.000000000000000);
--
select min_scale(numeric 'NaN') is NULL; -- should be true
select min_scale(numeric 'inf') is NULL; -- should be true
select min_scale(0); -- no digits
select min_scale(0.00); -- no digits again
select min_scale(1.0); -- no scale
@ -1070,6 +1244,7 @@ select min_scale(1e100); -- very big number
--
select trim_scale(numeric 'NaN');
select trim_scale(numeric 'inf');
select trim_scale(1.120);
select trim_scale(0);
select trim_scale(0.00);
@ -1096,7 +1271,11 @@ FROM (VALUES (0::numeric, 0::numeric),
(0::numeric, 46375::numeric),
(433125::numeric, 46375::numeric),
(43312.5::numeric, 4637.5::numeric),
(4331.250::numeric, 463.75000::numeric)) AS v(a, b);
(4331.250::numeric, 463.75000::numeric),
('inf', '0'),
('inf', '42'),
('inf', 'inf')
) AS v(a, b);
--
-- Tests for LCM()
@ -1108,7 +1287,11 @@ FROM (VALUES (0::numeric, 0::numeric),
(13272::numeric, 13272::numeric),
(423282::numeric, 13272::numeric),
(42328.2::numeric, 1327.2::numeric),
(4232.820::numeric, 132.72000::numeric)) AS v(a, b);
(4232.820::numeric, 132.72000::numeric),
('inf', '0'),
('inf', '42'),
('inf', 'inf')
) AS v(a, b);
SELECT lcm(9999 * (10::numeric)^131068 + (10::numeric^131068 - 1), 2); -- overflow

View File

@ -499,7 +499,7 @@ create temp table numerics(
);
insert into numerics values
(0, '-infinity', '-infinity', '-1000'), -- numeric type lacks infinities
(0, '-infinity', '-infinity', '-infinity'),
(1, -3, -3, -3),
(2, -1, -1, -1),
(3, 0, 0, 0),
@ -507,7 +507,7 @@ insert into numerics values
(5, 1.12, 1.12, 1.12),
(6, 2, 2, 2),
(7, 100, 100, 100),
(8, 'infinity', 'infinity', '1000'),
(8, 'infinity', 'infinity', 'infinity'),
(9, 'NaN', 'NaN', 'NaN');
select id, f_float4, first_value(id) over w, last_value(id) over w
@ -574,6 +574,18 @@ window w as (order by f_numeric range between
1 preceding and 1.1::float8 following); -- currently unsupported
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' preceding and 'inf' following);
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' preceding and 'inf' preceding);
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
'inf' following and 'inf' following);
select id, f_numeric, first_value(id) over w, last_value(id) over w
from numerics
window w as (order by f_numeric range between
1.1 preceding and 'NaN' following); -- error, NaN disallowed