Table of Contents
MySQL 5.0 introduces precision math: numeric value handling that results in more accurate results and more control over invalid values than in earlier versions of MySQL. Precision math is based on two implementation changes:
-
The introduction of SQL modes in MySQL 5.0 that control how strict the server is about accepting or rejecting invalid data.
-
The introduction in MySQL 5.0.3 of a library for fixed-point arithmetic.
These changes have several implications for numeric operations:
-
More precise calculations: For exact-value numbers, calculations do not introduce floating-point errors. Instead, exact precision is used. For example, a number such as
.0001
is treated as an exact value rather than as an approximation, and summing it 10,000 times produces a result of exactly1
, not a value that merely “close” to 1. -
Well-defined rounding behavior: For exact-value numbers, the result of
ROUND()
depends on its argument, not on environmental factors such as how the underlying C library works. -
Improved platform independence: Operations on exact numeric values are the same across different platforms such as Windows and Unix.
-
Control over handling of invalid values: Overflow and division by zero are detectable and can be treated as errors. For example, you can treat a value that is too large for a column as an error rather than having the value truncated to lie within the range of the column's data type. Similarly, you can treat division by zero as an error rather than as an operation that produces a result of
NULL
. The choice of which approach to take is determined by the setting of thesql_mode
system variable.
An important result of these changes is that MySQL provides improved compliance with standard SQL.
The following discussion covers several aspects of how precision
math works (including possible incompatibilities with older
applications). At the end, some examples are given that demonstrate
how MySQL 5.0 handles numeric operations precisely. For
information about using the sql_mode
system
variable to control the SQL mode, see
Section 5.2.5, “The Server SQL Mode”.
The scope of precision math for exact-value operations includes
the exact-value data types (DECIMAL
and integer
types) and exact-value numeric literals. Approximate-value data
types and numeric literals still are handled as floating-point
numbers.
Exact-value numeric literals have an integer part or fractional
part, or both. They may be signed. Examples: 1
,
.2
, 3.4
,
-5
, -6.78
,
+9.10
.
Approximate-value numeric literals are represented in scientific
notation with a mantissa and exponent. Either or both parts may be
signed. Examples: 1.2E3
,
1.2E-3
, -1.2E3
,
-1.2E-3
.
Two numbers that look similar need not be both exact-value or both
approximate-value. For example, 2.34
is an
exact-value (fixed-point) number, whereas
2.34E0
is an approximate-value (floating-point)
number.
The DECIMAL
data type is a fixed-point type and
calculations are exact. In MySQL, the DECIMAL
type has several synonyms: NUMERIC
,
DEC
, FIXED
. The integer
types also are exact-value types.
The FLOAT
and DOUBLE
data
types are floating-point types and calculations are approximate.
In MySQL, types that are synonymous with FLOAT
or DOUBLE
are DOUBLE
PRECISION
and REAL
.