Numeric Types
Applies to: ✅ Data Cloud SQL ✅ Tableau Hyper API
Numeric types consist of two, four, and eight-byte integers, eight-byte floating-point numbers, and selectable-precision decimals.
Name | Description | Precision |
---|---|---|
smallint | Small-range integer: | -32768 to +32767 (2 bytes) |
integer | Standard integer: | -2147483648 to +2147483647 (4 bytes) |
bigint | Large-range integer: | -9223372036854775808 to +9223372036854775807 (8 bytes) |
numeric | Exact, fixed-length representation of numbers with decimal point | Up to 38 decimal digits |
real | Inexact variable-precision | 6 decimal digits |
double precision | Inexact variable-precision | 15 decimal digits |
The types smallint
, integer
, and bigint
store whole numbers of various ranges. Attempts to store values outside the allowed range result in an error.
The type numeric
can store fixed-point numbers with up to 38 digits without loss of precision. We recommend numeric
to store monetary amounts and other quantities that require exactness. Calculations with numeric values yield exact results where possible.
We use these terms to describe a numeric value.
- Precision: the total count of significant digits in the whole number
- Scale: the count of decimal digits in the fractional part, to the right of the decimal point
So the number 23.5141 has a precision of six and a scale of four.
The maximum supported precision is 38. Internally, numeric
values are stored as 64-bit values if the precision is less than or equal to 18. Precisions over 18 require 128-bit for internal storage. Processing 128-bit numeric
values is often slower than processing 64-bit values.
You can store 128-bit numerics in .hyper
files with Tableau Hyper API by using database version 3 or newer.
You can configure the maximum precision and the maximum scale of a numeric
column. To declare a column of type numeric,
use the syntax NUMERIC(precision, scale)
. The precision is positive and the scale is zero or positive. By default, NUMERIC
selects the maximum precision of 38 and a scale of zero.
The type propagation rules for arithmetic operations with numerics can have larger precision and scale in the result type. A larger scale value can remove digits in front of the decimal point, which can lead to overflow errors. A larger precision value can slow down processing. To avoid this issue, add explicit casts to the scale and precision in the query. By default, the resulting precision is a maximum of 38.
Arithmetic operations between a NUMERIC(p1,s1)
and a NUMERIC(p2,s2)
have these results.
Operator | Result Type | Scale | Precision |
---|---|---|---|
+ or - | NUMERIC(precision, scale) | max(s1,s2) | max((p1-s1),(p2-s2)) + 1 + scale |
* | NUMERIC(precision, scale) | s1 + s2 | p1+p2 |
/ | NUMERIC(precision, scale) | max(6, s1 + p2 + 1) | p1 - s1 + s2 + max(6, s1 + p2 + 1) |
% | NUMERIC(precision, scale) | max(s1,s2) | min((p1-s1), (p2-s2)) + scale |
If the results precision for multiplication and division exceeds 38, the scale is reduced by the exceeding amount. During this step, the scale is never reduced to less than six.
DOUBLE PRECISION
operands always return DOUBLE PRECISION
results. SMALLINT
behaves the same as NUMERIC(5,0)
, INTEGER
as NUMERIC(10,0)
, and BIGINT
as NUMERIC(19,0)
.
In arithmetic operations with number literals, the literal is treated as the smallest fitting NUMERIC
type. For example, 100
is treated as NUMERIC(3,0)
. This rule only applies to literals, not to expressions containing literals. For example, (1+1)
is treated as NUMERIC(10,0)
, not NUMERIC(1,0)
.
If you create an extract of a relational database in Tableau, the extract uses the double precision
type with 15 digits of precision. However, you can create the extract file with the Tableau Hyper API and specify the numeric
type to return up to 38 digits.
The real
type has a range of 1E-37 and 1E+37 with a precision of at least 6 digits. The double precision
type has a range of around 1E-307 to 1E+308 with a precision of at least 15 digits. Values that are too large or too small cause errors. Numbers too close to zero that aren’t representable as distinct from zero cause an underflow error. Data Cloud SQL can round values if the precision of an input number is too high.
By default, floating point values are output in text form in their shortest precise decimal representation. This value uses at most 17 significant decimal digits.
In addition to ordinary numeric values, floating-point types have these special values.
Infinity
-Infinity
NaN
These values represent the IEEE 754 special values infinity, negative infinity, and not-a-number. To write these values as constants in an SQL command, put quotes around them. For example, UPDATE table SET x = '-Infinity'
. On input, these strings are recognized in a case-insensitive manner.
Data Cloud SQL supports float
and float(p)
for specifying inexact numeric types. p
is the minimum acceptable precision in binary digits. The types float(1)
to float(24)
are mapped to the real
type. The types float(25)
to float(53)
map to double precision
. By default, float
with no precision maps to double precision
.
You can store 32-bit floating values in .hyper
files by using Tableau Hyper API with database version 4 or newer.
Consider these recommendations for floating-point types.
-
If you require exact storage and calculations, such as for monetary amounts, use the
numeric
type instead. -
Aggregations such as
sum()
on floating-point values can yield inconsistent results if they’re run repeatedly due to parallel computation of aggregates. If you require consistent results, usenumeric
. -
Comparing two floating-point values for equality don’t always work as expected. Use difference to a small epsilon value.