MDEV-36851: COALESCE() returns nullable column while IFNULL() does not
Nullability is decided in two stages- 1. Based on argument NULL-ness Problem: - COALESCE currently uses a generic logic- "Result of a function is nullable if any of the arguments is nullable", which is wrong. - IFNULL sets nullability using second argument alone, which incorrectly sets the result to NULL even when first argument is not null. Fix: - Result of COALESCE and IFNULL is set to NULL only if all arguments are NULL. 2. Based on type conversion safety of fallback value Problem: - The generic `Item_hybrid_func_fix_attributes` logic would mark the function's result as nullable if any argument involved a type conversion that could yield NULL. Fix: - For COALESCE and IFNULL, nullability is set to NOT NULL if the first non-null argument can be safely converted to function's target return type. - For other functions, if any argument's conversion to target type could result in NULL, the function is marked nullable. Tests included in `mysql-test/main/func_hybrid_type.test`
This commit is contained in:
parent
c427618462
commit
bff9b1e472
@ -165,7 +165,7 @@ t1 CREATE TABLE `t1` (
|
||||
`COALESCE(1,1.0)` decimal(2,1) NOT NULL,
|
||||
`COALESCE(1,'1')` varchar(1) NOT NULL,
|
||||
`COALESCE(1.1,'1')` varchar(4) NOT NULL,
|
||||
`COALESCE('a' COLLATE latin1_bin,'b')` varchar(1) CHARACTER SET latin1 COLLATE latin1_bin DEFAULT NULL
|
||||
`COALESCE('a' COLLATE latin1_bin,'b')` varchar(1) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 SELECT IFNULL('a' COLLATE latin1_swedish_ci, 'b' COLLATE latin1_bin);
|
||||
|
@ -2621,7 +2621,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
|
||||
1234567
|
||||
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(a,'') 253 9 7 Y 128 39 63
|
||||
def COALESCE(a,'') 253 9 7 N 129 39 63
|
||||
COALESCE(a,'')
|
||||
1234567
|
||||
# All columns must be VARCHAR(9) with the same length:
|
||||
@ -2640,7 +2640,7 @@ t2 CREATE TABLE `t2` (
|
||||
`IFNULL(a,'')` varbinary(9) NOT NULL,
|
||||
`IF(a,a,'')` varbinary(9) DEFAULT NULL,
|
||||
`CASE WHEN a THEN a ELSE '' END` varbinary(9) DEFAULT NULL,
|
||||
`COALESCE(a,'')` varbinary(9) DEFAULT NULL
|
||||
`COALESCE(a,'')` varbinary(9) NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;
|
||||
|
@ -3033,7 +3033,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
|
||||
1234567
|
||||
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(a,'') 253 9 7 Y 0 39 51
|
||||
def COALESCE(a,'') 253 9 7 N 1 39 51
|
||||
COALESCE(a,'')
|
||||
1234567
|
||||
# All columns must be VARCHAR(9) with the same length:
|
||||
@ -3052,7 +3052,7 @@ t2 CREATE TABLE `t2` (
|
||||
`IFNULL(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci NOT NULL,
|
||||
`IF(a,a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL,
|
||||
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL,
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;
|
||||
|
@ -3342,7 +3342,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
|
||||
1234567
|
||||
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(a,'') 253 9 7 Y 0 39 8
|
||||
def COALESCE(a,'') 253 9 7 N 1 39 8
|
||||
COALESCE(a,'')
|
||||
1234567
|
||||
# All columns must be VARCHAR(9) with the same length:
|
||||
@ -3361,7 +3361,7 @@ t2 CREATE TABLE `t2` (
|
||||
`IFNULL(a,'')` varchar(9) NOT NULL,
|
||||
`IF(a,a,'')` varchar(9) DEFAULT NULL,
|
||||
`CASE WHEN a THEN a ELSE '' END` varchar(9) DEFAULT NULL,
|
||||
`COALESCE(a,'')` varchar(9) DEFAULT NULL
|
||||
`COALESCE(a,'')` varchar(9) NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;
|
||||
|
@ -4226,7 +4226,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
|
||||
1234567
|
||||
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(a,'') 253 9 7 Y 0 39 8
|
||||
def COALESCE(a,'') 253 9 7 N 1 39 8
|
||||
COALESCE(a,'')
|
||||
1234567
|
||||
# All columns must be VARCHAR(9) with the same length:
|
||||
@ -4245,7 +4245,7 @@ t2 CREATE TABLE `t2` (
|
||||
`IFNULL(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci NOT NULL,
|
||||
`IF(a,a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL,
|
||||
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL,
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;
|
||||
|
@ -5093,7 +5093,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
|
||||
1234567
|
||||
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(a,'') 253 27 7 Y 0 39 33
|
||||
def COALESCE(a,'') 253 27 7 N 1 39 33
|
||||
COALESCE(a,'')
|
||||
1234567
|
||||
# All columns must be VARCHAR(9) with the same length:
|
||||
@ -5112,7 +5112,7 @@ t2 CREATE TABLE `t2` (
|
||||
`IFNULL(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL,
|
||||
`IF(a,a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL,
|
||||
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL,
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL
|
||||
`COALESCE(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;
|
||||
|
@ -3430,7 +3430,7 @@ CASE WHEN TRUE THEN COALESCE(NULL) ELSE 4 END
|
||||
NULL
|
||||
SELECT COALESCE(COALESCE(NULL), 1.1) AS c0, IF(0, COALESCE(NULL), 1.1) AS c1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def c0 246 4 3 Y 32896 1 63
|
||||
def c0 246 4 3 N 32897 1 63
|
||||
def c1 246 4 3 Y 32896 1 63
|
||||
c0 c1
|
||||
1.1 1.1
|
||||
@ -3795,8 +3795,8 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`f0` decimal(1,0) DEFAULT NULL,
|
||||
`f1` decimal(1,0) DEFAULT NULL
|
||||
`f0` decimal(1,0) NOT NULL,
|
||||
`f1` decimal(1,0) NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t1, t2;
|
||||
SET sql_mode=DEFAULT;
|
||||
@ -4362,3 +4362,146 @@ LEAST( CAST( 0 AS CHAR ), OLD_PASSWORD( 1 ) )
|
||||
#
|
||||
# End of 10.6 tests
|
||||
#
|
||||
#
|
||||
# MDEV-36581: COALESCE() returns nullable column while IFNULL() does not
|
||||
#
|
||||
CREATE OR REPLACE VIEW test_coalesce_vs_ifnull AS
|
||||
SELECT
|
||||
COALESCE(operation_date, '1970-01-01 00:00:00') AS coalesced_date,
|
||||
IFNULL(operation_date, '1970-01-01 00:00:00') AS ifnull_date
|
||||
FROM (
|
||||
SELECT NULL AS operation_date
|
||||
) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_NAME = 'test_coalesce_vs_ifnull';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
coalesced_date NO varchar(19)
|
||||
ifnull_date NO varchar(19)
|
||||
DROP VIEW test_coalesce_vs_ifnull;
|
||||
CREATE VIEW v2 as SELECT COALESCE(c, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v2';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
c_col YES binary(0)
|
||||
i_col NO varchar(2)
|
||||
DROP VIEW v2;
|
||||
CREATE VIEW v3 as SELECT COALESCE(c, 10, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v3';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
c_col NO varchar(2)
|
||||
i_col NO varchar(2)
|
||||
DROP VIEW v3;
|
||||
CREATE VIEW v4 AS SELECT COALESCE(c, NULL, NULL) as c_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v4';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
c_col YES binary(0)
|
||||
DROP VIEW v4;
|
||||
CREATE VIEW v5 AS SELECT COALESCE(c, COALESCE(NULL, 10), NULL) as c_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v5';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
c_col NO varchar(2)
|
||||
DROP VIEW v5;
|
||||
CREATE TABLE t (c1 INT, c2 DOUBLE, c3 VARCHAR(5), c4 DATE);
|
||||
INSERT INTO t values (1, 2.3, 'four', '2025-05-06');
|
||||
SELECT COALESCE(c1, 10) AS coalesced_c1, IFNULL(c1, 10) AS ifnull_c1 FROM t;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c1 3 11 1 N 32897 0 63
|
||||
def ifnull_c1 3 11 1 N 32897 0 63
|
||||
coalesced_c1 ifnull_c1
|
||||
1 1
|
||||
SELECT COALESCE(c1, NULL) AS coalesced_c1, IFNULL(c1, NULL) AS ifnull_c1 FROM t;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c1 3 11 1 Y 32896 0 63
|
||||
def ifnull_c1 3 11 1 Y 32896 0 63
|
||||
coalesced_c1 ifnull_c1
|
||||
1 1
|
||||
SELECT COALESCE(c2, NULL) AS coalesced_c2, IFNULL(c2, NULL) as ifnull_c2 FROM t;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c2 5 22 3 Y 32896 31 63
|
||||
def ifnull_c2 5 22 3 Y 32896 31 63
|
||||
coalesced_c2 ifnull_c2
|
||||
2.3 2.3
|
||||
SELECT COALESCE(c3, 'two') as coalesced_c1, COALESCE(c4, '2025-07-08') AS coalesced_date FROM t;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c1 253 5 4 N 1 39 8
|
||||
def coalesced_date 253 10 10 N 1 39 8
|
||||
coalesced_c1 coalesced_date
|
||||
four 2025-05-06
|
||||
INSERT INTO t values (2, 3.4, NULL, NULL);
|
||||
SELECT COALESCE(c3, 'two') AS coalesced_c3, IFNULL(c3, 'three') AS ifnull_c3 FROM t WHERE c1 = 2;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c3 253 5 3 N 1 39 8
|
||||
def ifnull_c3 253 5 5 N 1 39 8
|
||||
coalesced_c3 ifnull_c3
|
||||
two three
|
||||
SELECT COALESCE(c3, 'four', NULL) AS coalesced_c3, COALESCE(COALESCE(c3, NULL), NULL) AS coalesced_c3_null FROM t WHERE c1 = 2;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_c3 253 5 4 N 1 39 8
|
||||
def coalesced_c3_null 253 5 0 Y 0 39 8
|
||||
coalesced_c3 coalesced_c3_null
|
||||
four NULL
|
||||
SELECT COALESCE(c4, COALESCE('2025-05-06', NULL)) AS coalesced_date FROM t WHERE c1 = 2;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def coalesced_date 253 10 10 N 1 39 8
|
||||
coalesced_date
|
||||
2025-05-06
|
||||
DROP TABLE t;
|
||||
SET sql_mode='';
|
||||
CREATE TABLE t1 (a UUID, b VARCHAR(32) NOT NULL);
|
||||
INSERT INTO t1 VALUES (NULL, '1');
|
||||
CREATE TABLE t2 AS SELECT COALESCE(a, b), IFNULL(a, b) FROM t1;
|
||||
Warnings:
|
||||
Warning 1292 Incorrect uuid value: '1'
|
||||
Warning 1292 Incorrect uuid value: '1'
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, b)` uuid DEFAULT NULL,
|
||||
`IFNULL(a, b)` uuid DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
COALESCE(a, b) YES uuid
|
||||
IFNULL(a, b) YES uuid
|
||||
DROP TABLE t1, t2;
|
||||
CREATE TABLE t (c1 INET6, c2 INET4);
|
||||
INSERT INTO t VALUES ('::', '0.0.0.0'), (NULL, NULL);
|
||||
CREATE TABLE t1 AS
|
||||
SELECT
|
||||
COALESCE(c1, '::1') AS inet6_c1_c, IFNULL(c1, '::1') AS inet6_c1_i,
|
||||
COALESCE(c2, '0.0.0.0') AS inet4_c2_c, IFNULL(c2, '0.0.0.0') AS inet4_c2_i
|
||||
FROM t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't1';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
inet6_c1_c NO inet6
|
||||
inet6_c1_i NO inet6
|
||||
inet4_c2_c NO inet4
|
||||
inet4_c2_i NO inet4
|
||||
CREATE TABLE t2 AS
|
||||
SELECT
|
||||
COALESCE(c1, 'ipv6') AS inet6_c1_c, IFNULL(c1, 'ipv6') AS inet6_c1_i,
|
||||
COALESCE(c2, 'ipv4') AS inet4_c2_c, IFNULL(c2, 'ipv4') AS inet4_c2_i
|
||||
FROM t;
|
||||
Warnings:
|
||||
Warning 1292 Incorrect inet6 value: 'ipv6'
|
||||
Warning 1292 Incorrect inet6 value: 'ipv6'
|
||||
Warning 1292 Incorrect inet4 value: 'ipv4'
|
||||
Warning 1292 Incorrect inet4 value: 'ipv4'
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
inet6_c1_c YES inet6
|
||||
inet6_c1_i YES inet6
|
||||
inet4_c2_c YES inet4
|
||||
inet4_c2_i YES inet4
|
||||
CREATE TABLE t3 AS SELECT COALESCE(c1, '::1') AS inet4_c1_c, IFNULL(c1, '::1') as inet6_c1_i FROM t WHERE c1 IS NULL;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
inet4_c1_c NO inet6
|
||||
inet6_c1_i NO inet6
|
||||
CREATE TABLE t4 AS SELECT COALESCE(c1, 'foo') AS inet4_c1_c, IFNULL(c1, 'bar') as inet6_c1_i FROM t WHERE c1 IS NOT NULL;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
|
||||
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
|
||||
inet4_c1_c NO inet6
|
||||
inet6_c1_i NO inet6
|
||||
DROP TABLE t, t1, t2, t3, t4;
|
||||
# End of 10.11 tests
|
||||
|
@ -1164,3 +1164,106 @@ SELECT LEAST( CAST( 0 AS CHAR ), OLD_PASSWORD( 1 ) );
|
||||
--echo #
|
||||
--echo # End of 10.6 tests
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-36581: COALESCE() returns nullable column while IFNULL() does not
|
||||
--echo #
|
||||
|
||||
CREATE OR REPLACE VIEW test_coalesce_vs_ifnull AS
|
||||
SELECT
|
||||
COALESCE(operation_date, '1970-01-01 00:00:00') AS coalesced_date,
|
||||
IFNULL(operation_date, '1970-01-01 00:00:00') AS ifnull_date
|
||||
FROM (
|
||||
SELECT NULL AS operation_date
|
||||
) AS t;
|
||||
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_NAME = 'test_coalesce_vs_ifnull';
|
||||
|
||||
DROP VIEW test_coalesce_vs_ifnull;
|
||||
|
||||
# Tests on views
|
||||
|
||||
CREATE VIEW v2 as SELECT COALESCE(c, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v2';
|
||||
|
||||
DROP VIEW v2;
|
||||
|
||||
CREATE VIEW v3 as SELECT COALESCE(c, 10, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v3';
|
||||
|
||||
DROP VIEW v3;
|
||||
|
||||
CREATE VIEW v4 AS SELECT COALESCE(c, NULL, NULL) as c_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v4';
|
||||
|
||||
DROP VIEW v4;
|
||||
|
||||
CREATE VIEW v5 AS SELECT COALESCE(c, COALESCE(NULL, 10), NULL) as c_col FROM (SELECT NULL AS c) AS t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v5';
|
||||
|
||||
DROP VIEW v5;
|
||||
|
||||
# Tests on tables
|
||||
|
||||
CREATE TABLE t (c1 INT, c2 DOUBLE, c3 VARCHAR(5), c4 DATE);
|
||||
INSERT INTO t values (1, 2.3, 'four', '2025-05-06');
|
||||
|
||||
--enable_metadata
|
||||
--disable_ps_protocol
|
||||
SELECT COALESCE(c1, 10) AS coalesced_c1, IFNULL(c1, 10) AS ifnull_c1 FROM t;
|
||||
SELECT COALESCE(c1, NULL) AS coalesced_c1, IFNULL(c1, NULL) AS ifnull_c1 FROM t;
|
||||
SELECT COALESCE(c2, NULL) AS coalesced_c2, IFNULL(c2, NULL) as ifnull_c2 FROM t;
|
||||
SELECT COALESCE(c3, 'two') as coalesced_c1, COALESCE(c4, '2025-07-08') AS coalesced_date FROM t;
|
||||
--enable_ps_protocol
|
||||
--disable_metadata
|
||||
|
||||
INSERT INTO t values (2, 3.4, NULL, NULL);
|
||||
--enable_metadata
|
||||
--disable_ps_protocol
|
||||
SELECT COALESCE(c3, 'two') AS coalesced_c3, IFNULL(c3, 'three') AS ifnull_c3 FROM t WHERE c1 = 2;
|
||||
SELECT COALESCE(c3, 'four', NULL) AS coalesced_c3, COALESCE(COALESCE(c3, NULL), NULL) AS coalesced_c3_null FROM t WHERE c1 = 2;
|
||||
SELECT COALESCE(c4, COALESCE('2025-05-06', NULL)) AS coalesced_date FROM t WHERE c1 = 2;
|
||||
--enable_ps_protocol
|
||||
--disable_metadata
|
||||
|
||||
DROP TABLE t;
|
||||
|
||||
# Case when one type cannot alwasy be converted to another safely
|
||||
SET sql_mode='';
|
||||
CREATE TABLE t1 (a UUID, b VARCHAR(32) NOT NULL);
|
||||
INSERT INTO t1 VALUES (NULL, '1');
|
||||
CREATE TABLE t2 AS SELECT COALESCE(a, b), IFNULL(a, b) FROM t1;
|
||||
|
||||
SHOW CREATE TABLE t2;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
|
||||
CREATE TABLE t (c1 INET6, c2 INET4);
|
||||
INSERT INTO t VALUES ('::', '0.0.0.0'), (NULL, NULL);
|
||||
|
||||
CREATE TABLE t1 AS
|
||||
SELECT
|
||||
COALESCE(c1, '::1') AS inet6_c1_c, IFNULL(c1, '::1') AS inet6_c1_i,
|
||||
COALESCE(c2, '0.0.0.0') AS inet4_c2_c, IFNULL(c2, '0.0.0.0') AS inet4_c2_i
|
||||
FROM t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't1';
|
||||
|
||||
CREATE TABLE t2 AS
|
||||
SELECT
|
||||
COALESCE(c1, 'ipv6') AS inet6_c1_c, IFNULL(c1, 'ipv6') AS inet6_c1_i,
|
||||
COALESCE(c2, 'ipv4') AS inet4_c2_c, IFNULL(c2, 'ipv4') AS inet4_c2_i
|
||||
FROM t;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
|
||||
|
||||
CREATE TABLE t3 AS SELECT COALESCE(c1, '::1') AS inet4_c1_c, IFNULL(c1, '::1') as inet6_c1_i FROM t WHERE c1 IS NULL;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
|
||||
|
||||
CREATE TABLE t4 AS SELECT COALESCE(c1, 'foo') AS inet4_c1_c, IFNULL(c1, 'bar') as inet6_c1_i FROM t WHERE c1 IS NOT NULL;
|
||||
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
|
||||
|
||||
DROP TABLE t, t1, t2, t3, t4;
|
||||
|
||||
--echo # End of 10.11 tests
|
||||
|
@ -5014,8 +5014,8 @@ LEAST(POINT(1,1),0x60);
|
||||
SHOW CREATE TABLE t1;
|
||||
Table Create Table
|
||||
t1 CREATE TABLE `t1` (
|
||||
`COALESCE(0x60,POINT(1,1))` longblob DEFAULT NULL,
|
||||
`COALESCE(POINT(1,1),0x60)` longblob DEFAULT NULL,
|
||||
`COALESCE(0x60,POINT(1,1))` longblob NOT NULL,
|
||||
`COALESCE(POINT(1,1),0x60)` longblob NOT NULL,
|
||||
`LEAST(0x60,POINT(1,1))` longblob DEFAULT NULL,
|
||||
`LEAST(POINT(1,1),0x60)` longblob DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
|
@ -263,11 +263,11 @@ t1 CREATE TABLE `t1` (
|
||||
`c01` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c02` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c03` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
|
||||
`c04` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c04` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
|
||||
`c05` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c06` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c07` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c08` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c07` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
|
||||
`c08` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
|
||||
`c09` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c10` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
`c11` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
|
||||
|
@ -825,12 +825,12 @@ c
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`c` decimal(1,0) DEFAULT NULL
|
||||
`c` decimal(1,0) NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
SELECT COALESCE(val, 1) FROM t1;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def COALESCE(val, 1) 246 2 1 Y 32896 0 63
|
||||
def COALESCE(val, 1) 246 2 1 N 32897 0 63
|
||||
COALESCE(val, 1)
|
||||
0
|
||||
DROP TABLE t1;
|
||||
|
@ -481,7 +481,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, '0.0.0.0')` inet4 DEFAULT NULL,
|
||||
`COALESCE(a, '0.0.0.0')` inet4 NOT NULL,
|
||||
`LEAST(a,'0.0.0.0')` inet4 DEFAULT NULL,
|
||||
`GREATEST(a,'0.0.0.0')` inet4 DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
@ -515,7 +515,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, 0x00000000)` inet4 DEFAULT NULL,
|
||||
`COALESCE(a, 0x00000000)` inet4 NOT NULL,
|
||||
`LEAST(a,0x00000000)` inet4 DEFAULT NULL,
|
||||
`GREATEST(a,0x00000000)` inet4 DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
@ -1928,7 +1928,7 @@ SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a,a)` inet4 NOT NULL,
|
||||
`COALESCE(a,b)` inet4 DEFAULT NULL
|
||||
`COALESCE(a,b)` inet4 NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT a AS ca,a AS cb FROM t1 UNION SELECT a,b FROM t1;
|
||||
|
@ -475,7 +475,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, '::')` inet6 DEFAULT NULL,
|
||||
`COALESCE(a, '::')` inet6 NOT NULL,
|
||||
`LEAST(a,'::')` inet6 DEFAULT NULL,
|
||||
`GREATEST(a,'::')` inet6 DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
@ -509,7 +509,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, 0x00000000000000000000000000000000)` inet6 DEFAULT NULL,
|
||||
`COALESCE(a, 0x00000000000000000000000000000000)` inet6 NOT NULL,
|
||||
`LEAST(a,0x00000000000000000000000000000000)` inet6 DEFAULT NULL,
|
||||
`GREATEST(a,0x00000000000000000000000000000000)` inet6 DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
@ -2108,7 +2108,7 @@ SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a,a)` inet6 NOT NULL,
|
||||
`COALESCE(a,b)` inet6 DEFAULT NULL
|
||||
`COALESCE(a,b)` inet6 NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
DROP TABLE t2;
|
||||
CREATE TABLE t2 AS SELECT a AS ca,a AS cb FROM t1 UNION SELECT a,b FROM t1;
|
||||
|
@ -318,9 +318,9 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`c1` test_double DEFAULT NULL,
|
||||
`c2` test_double DEFAULT NULL,
|
||||
`c3` test_double DEFAULT NULL
|
||||
`c1` test_double NOT NULL,
|
||||
`c2` test_double NOT NULL,
|
||||
`c3` test_double NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
SELECT * FROM t2 ORDER BY c1;
|
||||
c1 c2 c3
|
||||
|
@ -297,9 +297,9 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`c1` test_int8(20) DEFAULT NULL,
|
||||
`c2` decimal(20,1) DEFAULT NULL,
|
||||
`c3` double DEFAULT NULL
|
||||
`c1` test_int8(20) NOT NULL,
|
||||
`c2` decimal(20,1) NOT NULL,
|
||||
`c3` double NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
SELECT * FROM t2 ORDER BY c1;
|
||||
c1 c2 c3
|
||||
|
@ -1567,7 +1567,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, '00000000-0000-0000-0000-000000000000')` uuid DEFAULT NULL,
|
||||
`COALESCE(a, '00000000-0000-0000-0000-000000000000')` uuid NOT NULL,
|
||||
`LEAST(a,'00000000-0000-0000-0000-000000000000')` uuid DEFAULT NULL,
|
||||
`GREATEST(a,'00000000-0000-0000-0000-000000000000')` uuid DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
@ -1603,7 +1603,7 @@ FROM t1;
|
||||
SHOW CREATE TABLE t2;
|
||||
Table Create Table
|
||||
t2 CREATE TABLE `t2` (
|
||||
`COALESCE(a, 0x00000000000000000000000000000000)` uuid DEFAULT NULL,
|
||||
`COALESCE(a, 0x00000000000000000000000000000000)` uuid NOT NULL,
|
||||
`LEAST(a,0x00000000000000000000000000000000)` uuid DEFAULT NULL,
|
||||
`GREATEST(a,0x00000000000000000000000000000000)` uuid DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
|
||||
|
@ -1162,6 +1162,7 @@ public:
|
||||
bool native_op(THD *thd, Native *to) override;
|
||||
bool fix_length_and_dec(THD *thd) override
|
||||
{
|
||||
update_nullability_post_fix_fields();
|
||||
if (aggregate_for_result(func_name_cstring(), args, arg_count, true))
|
||||
return TRUE;
|
||||
fix_attributes(args, arg_count);
|
||||
@ -1246,17 +1247,7 @@ public:
|
||||
bool native_op(THD *thd, Native *to) override;
|
||||
bool fix_length_and_dec(THD *thd) override
|
||||
{
|
||||
/*
|
||||
Set nullability from args[1] by default.
|
||||
Note, some type handlers may reset maybe_null
|
||||
in Item_hybrid_func_fix_attributes() if args[1]
|
||||
is NOT NULL but cannot always be converted to
|
||||
the data type of "this" safely.
|
||||
E.g. Type_handler_inet6 does:
|
||||
IFNULL(inet6_not_null_expr, 'foo') -> INET6 NULL
|
||||
IFNULL(inet6_not_null_expr, '::1') -> INET6 NOT NULL
|
||||
*/
|
||||
copy_flags(args[1], item_base_t::MAYBE_NULL);
|
||||
update_nullability_post_fix_fields();
|
||||
if (Item_func_case_abbreviation2::fix_length_and_dec2(args))
|
||||
return TRUE;
|
||||
return FALSE;
|
||||
|
@ -291,6 +291,37 @@ bool Item_func::check_argument_types_scalar(uint start, uint end) const
|
||||
}
|
||||
|
||||
|
||||
/**
|
||||
@brief
|
||||
Update function's nullability based on nullness of its arguments
|
||||
|
||||
@details
|
||||
Functions like `IFNULL` and `COALESCE` decide nullability of their
|
||||
result after checking all the arguments. If any of the argument
|
||||
is NOT NULL, function's result is also set to NOT NULL.
|
||||
Note: Nullability determined here may be reset by type handlers in
|
||||
`Item_hybrid_func_fix_attributes()`, if the first non-null argument
|
||||
cannot be safely converted to target data type.
|
||||
E.g. Type_handler_inet6 does:
|
||||
IFNULL(inet6_not_null_expr, 'foo') -> INET6 NULL
|
||||
IFNULL(inet6_not_null_expr, '::1') -> INET6 NOT NULL
|
||||
*/
|
||||
void Item_func::update_nullability_post_fix_fields()
|
||||
{
|
||||
if (!maybe_null())
|
||||
return;
|
||||
|
||||
for (uint i= 0; i < arg_count; i++)
|
||||
{
|
||||
if (!args[i]->maybe_null())
|
||||
{
|
||||
base_flags &= ~item_base_t::MAYBE_NULL;
|
||||
break;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
Resolve references to table column for a function and its argument
|
||||
|
||||
|
@ -85,6 +85,8 @@ protected:
|
||||
return print_sql_mode_qualified_name(to, query_type, func_name_cstring());
|
||||
}
|
||||
|
||||
void update_nullability_post_fix_fields();
|
||||
|
||||
public:
|
||||
|
||||
// Print an error message for a builtin-schema qualified function call
|
||||
|
@ -1589,17 +1589,40 @@ public:
|
||||
- either by the most generic way in Item_func::fix_fields()
|
||||
- or by Item_func_xxx::fix_length_and_dec() before the call of
|
||||
Item_hybrid_func_fix_attributes()
|
||||
IFNULL() is special. It does not need to test args[0].
|
||||
IFNULL and COALESCE are special-
|
||||
If the first non-null arg can be safely converted to result type,
|
||||
the result is guaranteed to be NOT NULL
|
||||
*/
|
||||
uint first= dynamic_cast<Item_func_ifnull*>(attr) ? 1 : 0;
|
||||
for (uint i= first; i < nitems; i++)
|
||||
bool not_null_on_conversion= false;
|
||||
if (dynamic_cast<Item_func_ifnull*>(attr) ||
|
||||
dynamic_cast<Item_func_coalesce*>(attr))
|
||||
{
|
||||
if (Fbt::fix_fields_maybe_null_on_conversion_to_fbt(items[i]))
|
||||
for (uint i= 0; i< nitems; i++)
|
||||
{
|
||||
attr->set_type_maybe_null(true);
|
||||
break;
|
||||
if (!items[i]->maybe_null() &&
|
||||
!Fbt::fix_fields_maybe_null_on_conversion_to_fbt(items[i]))
|
||||
{
|
||||
not_null_on_conversion= true;
|
||||
break;
|
||||
}
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
not_null_on_conversion= true;
|
||||
for (uint i= 0; i < nitems; i++)
|
||||
{
|
||||
if (Fbt::fix_fields_maybe_null_on_conversion_to_fbt(items[i]))
|
||||
{
|
||||
not_null_on_conversion= false;
|
||||
break;
|
||||
}
|
||||
}
|
||||
}
|
||||
if (not_null_on_conversion)
|
||||
attr->set_type_maybe_null(false);
|
||||
else
|
||||
attr->set_type_maybe_null(true);
|
||||
return false;
|
||||
}
|
||||
bool Item_func_min_max_fix_attributes(THD *thd, Item_func_min_max *func,
|
||||
|
Loading…
x
Reference in New Issue
Block a user