Skip to content

Commit f8b4c99

Browse files
committed
Bug#34554755: DISTINCT on FLOAT values gives duplicates with SQL_BIG_RESULT
Values returned from operators that convert a value to FLOAT (that is, CAST(... AS FLOAT), CONVERT(..., FLOAT) or JSON_VALUE(... RETURNING FLOAT)) may have extra precision in their internal representation, since they are stored in double precision internally. This sometimes causes unexpected results when checking such values for equality. The symptoms include SELECT DISTINCT returning duplicates and comparison operators incorrectly reporting two equal values as not equal. Fixed by stripping off the extra double precision from the values before returning them. Also make conversion from float to string in these conversion operators use float format instead of double format. Change-Id: Id3dc86c6d791fce34a9e5b10a5b6097c336ed534
1 parent 0e935c9 commit f8b4c99

11 files changed

+134
-30
lines changed

Diff for: mysql-test/r/cast.result

+16
Original file line numberDiff line numberDiff line change
@@ -2276,3 +2276,19 @@ Warning 1287 Setting user variables within expressions is deprecated and will be
22762276
Warning 3020 Invalid argument for logarithm
22772277
set @a:= @b;
22782278
do convert(@a using latin1);
2279+
#
2280+
# Bug#34554755: DISTINCT on FLOAT values gives duplicates
2281+
# with SQL_BIG_RESULT
2282+
#
2283+
SELECT CAST(1111111111111111 AS FLOAT) = CAST(1111111111111110 AS FLOAT) AS eq;
2284+
eq
2285+
1
2286+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS CHAR) AS v;
2287+
v
2288+
1.11111e15
2289+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS SIGNED) AS v;
2290+
v
2291+
1111111126482944
2292+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS DECIMAL(20,2)) AS v;
2293+
v
2294+
1111111126482944.00

Diff for: mysql-test/r/distinct.result

-4
Original file line numberDiff line numberDiff line change
@@ -1414,10 +1414,6 @@ CAST(v AS FLOAT)
14141414
-2007570000
14151415
-2007570000
14161416
-2007570000
1417-
-2007570000
1418-
-2007570000
1419-
2007570000
1420-
2007570000
14211417
2007570000
14221418
2007570000
14231419
2007570000

Diff for: mysql-test/suite/json/r/json_value.result

+38-2
Original file line numberDiff line numberDiff line change
@@ -862,7 +862,7 @@ JSON_VALUE('1', '$' RETURNING JSON) + 1.0e0
862862
2
863863
SELECT JSON_VALUE('1.2', '$' RETURNING FLOAT) + 1.0e0;
864864
JSON_VALUE('1.2', '$' RETURNING FLOAT) + 1.0e0
865-
2.2
865+
2.200000047683716
866866
SELECT JSON_VALUE('1988', '$' RETURNING YEAR) + 1.0e0;
867867
JSON_VALUE('1988', '$' RETURNING YEAR) + 1.0e0
868868
1989
@@ -1020,11 +1020,15 @@ SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
10201020
TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
10211021
'$' RETURNING DECIMAL(14, 0)))
10221022
2000-01-02 12:14:14
1023+
# Warns because 20000102121314 gets truncated to fit in a FLOAT,
1024+
# and is not a valid timestamp after truncation.
10231025
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
10241026
'$' RETURNING FLOAT));
10251027
TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
10261028
'$' RETURNING FLOAT))
1027-
2000-01-02 12:14:14
1029+
NULL
1030+
Warnings:
1031+
Warning 1292 Incorrect datetime value: '20000102416384'
10281032
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
10291033
'$' RETURNING DOUBLE));
10301034
TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
@@ -1347,6 +1351,7 @@ Note 1003 /* select#1 */ select `test`.`t1`.`j` AS `j` from `test`.`t1` where (j
13471351
SELECT * FROM t1
13481352
WHERE JSON_VALUE(j, '$' RETURNING FLOAT) = CAST(3.3 AS FLOAT);
13491353
j
1354+
3.3
13501355
# The index is not used if the JSON_VALUE expressions differ.
13511356
EXPLAIN SELECT * FROM t1
13521357
WHERE JSON_VALUE(j, '$' RETURNING DOUBLE) = CAST(3.3 AS FLOAT);
@@ -1811,3 +1816,34 @@ SELECT JSON_VALUE(JSON_OBJECT('a', 'value'), '$.a'),
18111816
JSON_VALUE(JSON_OBJECT('a', NULL), '$.a');
18121817
JSON_VALUE(JSON_OBJECT('a', 'value'), '$.a') JSON_VALUE(JSON_OBJECT('a', NULL), '$.a')
18131818
value NULL
1819+
#
1820+
# Bug#34554755: DISTINCT on FLOAT values gives duplicates
1821+
# with SQL_BIG_RESULT
1822+
#
1823+
SELECT JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) =
1824+
JSON_VALUE('1111111111111110', '$' RETURNING FLOAT) AS eq;
1825+
eq
1826+
1
1827+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) AS CHAR) AS v;
1828+
v
1829+
1.11111e15
1830+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) AS SIGNED) AS v;
1831+
v
1832+
1111111126482944
1833+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT)
1834+
AS DECIMAL(20,2)) AS res;
1835+
res
1836+
1111111126482944.00
1837+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1838+
DEFAULT 1111111111111111 ON EMPTY) AS CHAR) AS v;
1839+
v
1840+
1.11111e15
1841+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1842+
DEFAULT 1111111111111111 ON EMPTY) AS SIGNED) AS v;
1843+
v
1844+
1111111126482944
1845+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1846+
DEFAULT 1111111111111111 ON EMPTY)
1847+
AS DECIMAL(20,2)) AS v;
1848+
v
1849+
1111111126482944.00

Diff for: mysql-test/suite/json/t/json_value.test

+25
Original file line numberDiff line numberDiff line change
@@ -706,6 +706,8 @@ SET TIMESTAMP=DEFAULT;
706706
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('"2000-01-02 12:13:14"', '$'));
707707
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
708708
'$' RETURNING DECIMAL(14, 0)));
709+
--echo # Warns because 20000102121314 gets truncated to fit in a FLOAT,
710+
--echo # and is not a valid timestamp after truncation.
709711
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
710712
'$' RETURNING FLOAT));
711713
SELECT TIMESTAMPADD(MINUTE, 1, JSON_VALUE('20000102121314',
@@ -1193,3 +1195,26 @@ SELECT JSON_VALUE(JSON_OBJECT('a', FALSE), '$.a' RETURNING SIGNED),
11931195
# As CHAR:
11941196
SELECT JSON_VALUE(JSON_OBJECT('a', 'value'), '$.a'),
11951197
JSON_VALUE(JSON_OBJECT('a', NULL), '$.a');
1198+
1199+
--echo #
1200+
--echo # Bug#34554755: DISTINCT on FLOAT values gives duplicates
1201+
--echo # with SQL_BIG_RESULT
1202+
--echo #
1203+
1204+
# These two integers map to the same FLOAT value, so the comparison
1205+
# should return TRUE.
1206+
SELECT JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) =
1207+
JSON_VALUE('1111111111111110', '$' RETURNING FLOAT) AS eq;
1208+
1209+
# Converting the FLOAT to other types should not keep the full DOUBLE precision.
1210+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) AS CHAR) AS v;
1211+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT) AS SIGNED) AS v;
1212+
SELECT CAST(JSON_VALUE('1111111111111111', '$' RETURNING FLOAT)
1213+
AS DECIMAL(20,2)) AS res;
1214+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1215+
DEFAULT 1111111111111111 ON EMPTY) AS CHAR) AS v;
1216+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1217+
DEFAULT 1111111111111111 ON EMPTY) AS SIGNED) AS v;
1218+
SELECT CAST(JSON_VALUE('{}', '$.a' RETURNING FLOAT
1219+
DEFAULT 1111111111111111 ON EMPTY)
1220+
AS DECIMAL(20,2)) AS v;

Diff for: mysql-test/suite/rpl/r/rpl_cast.result

+5-5
Original file line numberDiff line numberDiff line change
@@ -33,11 +33,11 @@ id bt vt tt ft it itu jt dt dc dat yt
3333
5 json 4827410.7404 -87484.874897447 -4873280 5398432 8549 8392 -892472.8748931 49852.53985000 2020-02-20 2020
3434
SELECT * FROM wl529_insert;
3535
f1 f2 f3 f4 f5 f6 f7 f8 f9 f10 f11
36-
0 837498713.84728 8240921.0982421 9385.8251953125 1234 12984 3980921 98453.8324732 4824.892470000000000000000000000000 20110403 2012.0000000000
37-
0 -494804.48724 48744.84783 1234.122314453125 -1234 938432 9218421 384734.84732 589239.948091000000000000000000000000 20101111 2010.0000000000
38-
0 7848094.874821 48973847.8743 3875329 3473 3984010 1 -8478.89247 -402984.874200000000000000000000000000 19800101 1980.0000000000
39-
0 908249214.8742 7634109.984304 -9824821 -98347 3814030 8742.43 -384731.837438 -4824.892470000000000000000000000000 19700101 1970.0000000000
40-
0 4827410.7404 -87484.874897447 -4873285 5398430 8549 8392 -892472.8748931 49852.539850000000000000000000000000 20200220 2020.0000000000
36+
0 837498688 8240921 9385.8251953125 1234 12984 3980921 98453.8359375 4824.892578125000000000000000000000 20110404 2012.0000000000
37+
0 -494804.5 48744.84765625 1234.122314453125 -1234 938432 9218421 384734.84375 589239.937500000000000000000000000000 20101112 2010.0000000000
38+
0 7848095 48973848 3875329 3473 3984010 1 -8478.892578125 -402984.875000000000000000000000000000 19800100 1980.0000000000
39+
0 908249216 7634110 -9824821 -98347 3814030 8742.4296875 -384731.84375 -4824.892578125000000000000000000000 19700100 1970.0000000000
40+
0 4827410.5 -87484.875 -4873285 5398430 8549 8392 -892472.875 49852.539062500000000000000000000000 20200220 2020.0000000000
4141
0 837498713.84728 8240921.0982421 9385.8251953125 1234 12984 3980921 98453.8324732 4824.892470000000000000000000000000 20110403 2012.0000000000
4242
0 -494804.48724 48744.84783 1234.122314453125 -1234 938432 9218421 384734.84732 589239.948091000000000000000000000000 20101111 2010.0000000000
4343
0 7848094.874821 48973847.8743 3875329 3473 3984010 1 -8478.89247 -402984.874200000000000000000000000000 19800101 1980.0000000000

Diff for: mysql-test/t/cast.test

+14
Original file line numberDiff line numberDiff line change
@@ -1132,3 +1132,17 @@ DROP TABLE t;
11321132
set @a:= st_aswkb(st_astext(@b:=log10(0.0)));
11331133
set @a:= @b;
11341134
do convert(@a using latin1);
1135+
1136+
--echo #
1137+
--echo # Bug#34554755: DISTINCT on FLOAT values gives duplicates
1138+
--echo # with SQL_BIG_RESULT
1139+
--echo #
1140+
1141+
# These two integers map to the same FLOAT value, so the comparison
1142+
# should return TRUE.
1143+
SELECT CAST(1111111111111111 AS FLOAT) = CAST(1111111111111110 AS FLOAT) AS eq;
1144+
1145+
# Converting the FLOAT to other types should not keep the full DOUBLE precision.
1146+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS CHAR) AS v;
1147+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS SIGNED) AS v;
1148+
SELECT CAST(CAST(1111111111111111 AS FLOAT) AS DECIMAL(20,2)) AS v;

Diff for: mysql-test/t/distinct.test

-1
Original file line numberDiff line numberDiff line change
@@ -985,7 +985,6 @@ INSERT INTO t1 VALUES
985985
(2007568257), (2007568260), (2007570000), (2007567234), (2007567230);
986986

987987
SELECT SQL_SMALL_RESULT DISTINCT CAST(v AS FLOAT) FROM t1;
988-
--skip_if_hypergraph # Incorrect results recorded. Bug#34554755.
989988
SELECT SQL_BIG_RESULT DISTINCT CAST(v AS FLOAT) FROM t1;
990989

991990
DROP TABLE t1;

Diff for: sql/filesort.cc

-6
Original file line numberDiff line numberDiff line change
@@ -1356,12 +1356,6 @@ size_t make_sortkey_from_item(Item *item, Item_result result_type,
13561356
case REAL_RESULT: {
13571357
assert(!is_varlen);
13581358
double value = item->val_real();
1359-
if (item->data_type() == MYSQL_TYPE_FLOAT) {
1360-
// Get rid of extra precision. Otherwise, duplicate removal may make the
1361-
// wrong decision and treat equal values as distinct values due to
1362-
// differences in the insignificant digits.
1363-
value = static_cast<float>(value);
1364-
}
13651359
if (item->null_value) {
13661360
assert(item->is_nullable());
13671361
*null_indicator = 0;

Diff for: sql/item.cc

+17-1
Original file line numberDiff line numberDiff line change
@@ -263,7 +263,23 @@ String *Item::val_str_ascii(String *str) {
263263
String *Item::val_string_from_real(String *str) {
264264
double nr = val_real();
265265
if (null_value) return nullptr; /* purecov: inspected */
266-
str->set_real(nr, decimals, &my_charset_bin);
266+
267+
char buffer[FLOATING_POINT_BUFFER];
268+
size_t len;
269+
if (data_type() == MYSQL_TYPE_FLOAT) {
270+
len = my_gcvt(nr, MY_GCVT_ARG_FLOAT, MAX_FLOAT_STR_LENGTH, buffer,
271+
/*error=*/nullptr);
272+
} else {
273+
len = my_gcvt(nr, MY_GCVT_ARG_DOUBLE, MAX_DOUBLE_STR_LENGTH, buffer,
274+
/*error=*/nullptr);
275+
}
276+
277+
uint dummy_errors;
278+
if (str->copy(buffer, len, &my_charset_numeric, collation.collation,
279+
&dummy_errors)) {
280+
return error_str();
281+
}
282+
267283
return str;
268284
}
269285

Diff for: sql/item_func.cc

+8-9
Original file line numberDiff line numberDiff line change
@@ -1994,21 +1994,20 @@ void Item_typecast_decimal::print(const THD *thd, String *str,
19941994
}
19951995

19961996
String *Item_typecast_real::val_str(String *str) {
1997-
double res = val_real();
1998-
if (null_value) return nullptr;
1999-
2000-
str->set_real(res, decimals, collation.collation);
2001-
return str;
1997+
return val_string_from_real(str);
20021998
}
20031999

20042000
double Item_typecast_real::val_real() {
20052001
double res = args[0]->val_real();
20062002
null_value = args[0]->null_value;
20072003
if (null_value) return 0.0;
2008-
if (data_type() == MYSQL_TYPE_FLOAT &&
2009-
((res > std::numeric_limits<float>::max()) ||
2010-
res < std::numeric_limits<float>::lowest()))
2011-
return raise_float_overflow();
2004+
if (data_type() == MYSQL_TYPE_FLOAT) {
2005+
if (res > std::numeric_limits<float>::max() ||
2006+
res < std::numeric_limits<float>::lowest()) {
2007+
return raise_float_overflow();
2008+
}
2009+
res = static_cast<float>(res);
2010+
}
20122011
return check_float_overflow(res);
20132012
}
20142013

Diff for: sql/item_json_func.cc

+11-2
Original file line numberDiff line numberDiff line change
@@ -4396,7 +4396,9 @@ Item_func_json_value::create_json_value_default(THD *thd, Item *item) {
43964396
my_error(ER_DATA_OUT_OF_RANGE, MYF(0), "FLOAT DEFAULT", func_name());
43974397
return nullptr;
43984398
}
4399-
default_value->real_default = value;
4399+
// The value is within range of FLOAT. Finally, cast it to float to get
4400+
// rid of any extra (double) precision that doesn't fit in a FLOAT.
4401+
default_value->real_default = static_cast<float>(value);
44004402
break;
44014403
}
44024404
case ITEM_CAST_DOUBLE: {
@@ -5229,7 +5231,14 @@ double Item_func_json_value::extract_real_value() {
52295231

52305232
bool err = false;
52315233
double value = wr.coerce_real(func_name(), CE_IGNORE, &err);
5232-
if (!err) return value;
5234+
if (!err) {
5235+
if (data_type() == MYSQL_TYPE_FLOAT) {
5236+
// Remove any extra (double) precision.
5237+
return static_cast<float>(value);
5238+
} else {
5239+
return value;
5240+
}
5241+
}
52335242

52345243
if (handle_json_value_conversion_error(
52355244
m_on_error, data_type() == MYSQL_TYPE_DOUBLE ? "DOUBLE" : "FLOAT",

0 commit comments

Comments
 (0)