Skip to content

Commit bff9b1e

Browse files
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`
1 parent c427618 commit bff9b1e

20 files changed

+345
-52
lines changed

mysql-test/main/case.result

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -165,7 +165,7 @@ t1 CREATE TABLE `t1` (
165165
`COALESCE(1,1.0)` decimal(2,1) NOT NULL,
166166
`COALESCE(1,'1')` varchar(1) NOT NULL,
167167
`COALESCE(1.1,'1')` varchar(4) NOT NULL,
168-
`COALESCE('a' COLLATE latin1_bin,'b')` varchar(1) CHARACTER SET latin1 COLLATE latin1_bin DEFAULT NULL
168+
`COALESCE('a' COLLATE latin1_bin,'b')` varchar(1) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL
169169
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
170170
DROP TABLE t1;
171171
CREATE TABLE t1 SELECT IFNULL('a' COLLATE latin1_swedish_ci, 'b' COLLATE latin1_bin);

mysql-test/main/ctype_binary.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -2621,7 +2621,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
26212621
1234567
26222622
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
26232623
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
2624-
def COALESCE(a,'') 253 9 7 Y 128 39 63
2624+
def COALESCE(a,'') 253 9 7 N 129 39 63
26252625
COALESCE(a,'')
26262626
1234567
26272627
# All columns must be VARCHAR(9) with the same length:
@@ -2640,7 +2640,7 @@ t2 CREATE TABLE `t2` (
26402640
`IFNULL(a,'')` varbinary(9) NOT NULL,
26412641
`IF(a,a,'')` varbinary(9) DEFAULT NULL,
26422642
`CASE WHEN a THEN a ELSE '' END` varbinary(9) DEFAULT NULL,
2643-
`COALESCE(a,'')` varbinary(9) DEFAULT NULL
2643+
`COALESCE(a,'')` varbinary(9) NOT NULL
26442644
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
26452645
DROP TABLE t2;
26462646
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;

mysql-test/main/ctype_cp1251.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -3033,7 +3033,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
30333033
1234567
30343034
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
30353035
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
3036-
def COALESCE(a,'') 253 9 7 Y 0 39 51
3036+
def COALESCE(a,'') 253 9 7 N 1 39 51
30373037
COALESCE(a,'')
30383038
1234567
30393039
# All columns must be VARCHAR(9) with the same length:
@@ -3052,7 +3052,7 @@ t2 CREATE TABLE `t2` (
30523052
`IFNULL(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci NOT NULL,
30533053
`IF(a,a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL,
30543054
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL,
3055-
`COALESCE(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci DEFAULT NULL
3055+
`COALESCE(a,'')` varchar(9) CHARACTER SET cp1251 COLLATE cp1251_general_ci NOT NULL
30563056
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
30573057
DROP TABLE t2;
30583058
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;

mysql-test/main/ctype_latin1.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -3342,7 +3342,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
33423342
1234567
33433343
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
33443344
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
3345-
def COALESCE(a,'') 253 9 7 Y 0 39 8
3345+
def COALESCE(a,'') 253 9 7 N 1 39 8
33463346
COALESCE(a,'')
33473347
1234567
33483348
# All columns must be VARCHAR(9) with the same length:
@@ -3361,7 +3361,7 @@ t2 CREATE TABLE `t2` (
33613361
`IFNULL(a,'')` varchar(9) NOT NULL,
33623362
`IF(a,a,'')` varchar(9) DEFAULT NULL,
33633363
`CASE WHEN a THEN a ELSE '' END` varchar(9) DEFAULT NULL,
3364-
`COALESCE(a,'')` varchar(9) DEFAULT NULL
3364+
`COALESCE(a,'')` varchar(9) NOT NULL
33653365
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
33663366
DROP TABLE t2;
33673367
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;

mysql-test/main/ctype_ucs.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4226,7 +4226,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
42264226
1234567
42274227
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
42284228
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4229-
def COALESCE(a,'') 253 9 7 Y 0 39 8
4229+
def COALESCE(a,'') 253 9 7 N 1 39 8
42304230
COALESCE(a,'')
42314231
1234567
42324232
# All columns must be VARCHAR(9) with the same length:
@@ -4245,7 +4245,7 @@ t2 CREATE TABLE `t2` (
42454245
`IFNULL(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci NOT NULL,
42464246
`IF(a,a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL,
42474247
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL,
4248-
`COALESCE(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci DEFAULT NULL
4248+
`COALESCE(a,'')` varchar(9) CHARACTER SET ucs2 COLLATE ucs2_general_ci NOT NULL
42494249
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
42504250
DROP TABLE t2;
42514251
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;

mysql-test/main/ctype_utf8.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -5093,7 +5093,7 @@ GROUP_CONCAT(CASE WHEN a THEN a ELSE '' END)
50935093
1234567
50945094
SELECT COALESCE(a,'') FROM t1 GROUP BY 1;
50955095
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
5096-
def COALESCE(a,'') 253 27 7 Y 0 39 33
5096+
def COALESCE(a,'') 253 27 7 N 1 39 33
50975097
COALESCE(a,'')
50985098
1234567
50995099
# All columns must be VARCHAR(9) with the same length:
@@ -5112,7 +5112,7 @@ t2 CREATE TABLE `t2` (
51125112
`IFNULL(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL,
51135113
`IF(a,a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL,
51145114
`CASE WHEN a THEN a ELSE '' END` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL,
5115-
`COALESCE(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci DEFAULT NULL
5115+
`COALESCE(a,'')` varchar(9) CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL
51165116
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
51175117
DROP TABLE t2;
51185118
CREATE TABLE t2 AS SELECT CONCAT_WS(1,2,3) FROM t1;

mysql-test/main/func_hybrid_type.result

Lines changed: 146 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -3430,7 +3430,7 @@ CASE WHEN TRUE THEN COALESCE(NULL) ELSE 4 END
34303430
NULL
34313431
SELECT COALESCE(COALESCE(NULL), 1.1) AS c0, IF(0, COALESCE(NULL), 1.1) AS c1;
34323432
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
3433-
def c0 246 4 3 Y 32896 1 63
3433+
def c0 246 4 3 N 32897 1 63
34343434
def c1 246 4 3 Y 32896 1 63
34353435
c0 c1
34363436
1.1 1.1
@@ -3795,8 +3795,8 @@ FROM t1;
37953795
SHOW CREATE TABLE t2;
37963796
Table Create Table
37973797
t2 CREATE TABLE `t2` (
3798-
`f0` decimal(1,0) DEFAULT NULL,
3799-
`f1` decimal(1,0) DEFAULT NULL
3798+
`f0` decimal(1,0) NOT NULL,
3799+
`f1` decimal(1,0) NOT NULL
38003800
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
38013801
DROP TABLE t1, t2;
38023802
SET sql_mode=DEFAULT;
@@ -4362,3 +4362,146 @@ LEAST( CAST( 0 AS CHAR ), OLD_PASSWORD( 1 ) )
43624362
#
43634363
# End of 10.6 tests
43644364
#
4365+
#
4366+
# MDEV-36581: COALESCE() returns nullable column while IFNULL() does not
4367+
#
4368+
CREATE OR REPLACE VIEW test_coalesce_vs_ifnull AS
4369+
SELECT
4370+
COALESCE(operation_date, '1970-01-01 00:00:00') AS coalesced_date,
4371+
IFNULL(operation_date, '1970-01-01 00:00:00') AS ifnull_date
4372+
FROM (
4373+
SELECT NULL AS operation_date
4374+
) AS t;
4375+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE
4376+
FROM INFORMATION_SCHEMA.COLUMNS
4377+
WHERE TABLE_NAME = 'test_coalesce_vs_ifnull';
4378+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4379+
coalesced_date NO varchar(19)
4380+
ifnull_date NO varchar(19)
4381+
DROP VIEW test_coalesce_vs_ifnull;
4382+
CREATE VIEW v2 as SELECT COALESCE(c, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
4383+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v2';
4384+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4385+
c_col YES binary(0)
4386+
i_col NO varchar(2)
4387+
DROP VIEW v2;
4388+
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;
4389+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v3';
4390+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4391+
c_col NO varchar(2)
4392+
i_col NO varchar(2)
4393+
DROP VIEW v3;
4394+
CREATE VIEW v4 AS SELECT COALESCE(c, NULL, NULL) as c_col FROM (SELECT NULL AS c) AS t;
4395+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v4';
4396+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4397+
c_col YES binary(0)
4398+
DROP VIEW v4;
4399+
CREATE VIEW v5 AS SELECT COALESCE(c, COALESCE(NULL, 10), NULL) as c_col FROM (SELECT NULL AS c) AS t;
4400+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v5';
4401+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4402+
c_col NO varchar(2)
4403+
DROP VIEW v5;
4404+
CREATE TABLE t (c1 INT, c2 DOUBLE, c3 VARCHAR(5), c4 DATE);
4405+
INSERT INTO t values (1, 2.3, 'four', '2025-05-06');
4406+
SELECT COALESCE(c1, 10) AS coalesced_c1, IFNULL(c1, 10) AS ifnull_c1 FROM t;
4407+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4408+
def coalesced_c1 3 11 1 N 32897 0 63
4409+
def ifnull_c1 3 11 1 N 32897 0 63
4410+
coalesced_c1 ifnull_c1
4411+
1 1
4412+
SELECT COALESCE(c1, NULL) AS coalesced_c1, IFNULL(c1, NULL) AS ifnull_c1 FROM t;
4413+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4414+
def coalesced_c1 3 11 1 Y 32896 0 63
4415+
def ifnull_c1 3 11 1 Y 32896 0 63
4416+
coalesced_c1 ifnull_c1
4417+
1 1
4418+
SELECT COALESCE(c2, NULL) AS coalesced_c2, IFNULL(c2, NULL) as ifnull_c2 FROM t;
4419+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4420+
def coalesced_c2 5 22 3 Y 32896 31 63
4421+
def ifnull_c2 5 22 3 Y 32896 31 63
4422+
coalesced_c2 ifnull_c2
4423+
2.3 2.3
4424+
SELECT COALESCE(c3, 'two') as coalesced_c1, COALESCE(c4, '2025-07-08') AS coalesced_date FROM t;
4425+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4426+
def coalesced_c1 253 5 4 N 1 39 8
4427+
def coalesced_date 253 10 10 N 1 39 8
4428+
coalesced_c1 coalesced_date
4429+
four 2025-05-06
4430+
INSERT INTO t values (2, 3.4, NULL, NULL);
4431+
SELECT COALESCE(c3, 'two') AS coalesced_c3, IFNULL(c3, 'three') AS ifnull_c3 FROM t WHERE c1 = 2;
4432+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4433+
def coalesced_c3 253 5 3 N 1 39 8
4434+
def ifnull_c3 253 5 5 N 1 39 8
4435+
coalesced_c3 ifnull_c3
4436+
two three
4437+
SELECT COALESCE(c3, 'four', NULL) AS coalesced_c3, COALESCE(COALESCE(c3, NULL), NULL) AS coalesced_c3_null FROM t WHERE c1 = 2;
4438+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4439+
def coalesced_c3 253 5 4 N 1 39 8
4440+
def coalesced_c3_null 253 5 0 Y 0 39 8
4441+
coalesced_c3 coalesced_c3_null
4442+
four NULL
4443+
SELECT COALESCE(c4, COALESCE('2025-05-06', NULL)) AS coalesced_date FROM t WHERE c1 = 2;
4444+
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
4445+
def coalesced_date 253 10 10 N 1 39 8
4446+
coalesced_date
4447+
2025-05-06
4448+
DROP TABLE t;
4449+
SET sql_mode='';
4450+
CREATE TABLE t1 (a UUID, b VARCHAR(32) NOT NULL);
4451+
INSERT INTO t1 VALUES (NULL, '1');
4452+
CREATE TABLE t2 AS SELECT COALESCE(a, b), IFNULL(a, b) FROM t1;
4453+
Warnings:
4454+
Warning 1292 Incorrect uuid value: '1'
4455+
Warning 1292 Incorrect uuid value: '1'
4456+
SHOW CREATE TABLE t2;
4457+
Table Create Table
4458+
t2 CREATE TABLE `t2` (
4459+
`COALESCE(a, b)` uuid DEFAULT NULL,
4460+
`IFNULL(a, b)` uuid DEFAULT NULL
4461+
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci
4462+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
4463+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4464+
COALESCE(a, b) YES uuid
4465+
IFNULL(a, b) YES uuid
4466+
DROP TABLE t1, t2;
4467+
CREATE TABLE t (c1 INET6, c2 INET4);
4468+
INSERT INTO t VALUES ('::', '0.0.0.0'), (NULL, NULL);
4469+
CREATE TABLE t1 AS
4470+
SELECT
4471+
COALESCE(c1, '::1') AS inet6_c1_c, IFNULL(c1, '::1') AS inet6_c1_i,
4472+
COALESCE(c2, '0.0.0.0') AS inet4_c2_c, IFNULL(c2, '0.0.0.0') AS inet4_c2_i
4473+
FROM t;
4474+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't1';
4475+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4476+
inet6_c1_c NO inet6
4477+
inet6_c1_i NO inet6
4478+
inet4_c2_c NO inet4
4479+
inet4_c2_i NO inet4
4480+
CREATE TABLE t2 AS
4481+
SELECT
4482+
COALESCE(c1, 'ipv6') AS inet6_c1_c, IFNULL(c1, 'ipv6') AS inet6_c1_i,
4483+
COALESCE(c2, 'ipv4') AS inet4_c2_c, IFNULL(c2, 'ipv4') AS inet4_c2_i
4484+
FROM t;
4485+
Warnings:
4486+
Warning 1292 Incorrect inet6 value: 'ipv6'
4487+
Warning 1292 Incorrect inet6 value: 'ipv6'
4488+
Warning 1292 Incorrect inet4 value: 'ipv4'
4489+
Warning 1292 Incorrect inet4 value: 'ipv4'
4490+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
4491+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4492+
inet6_c1_c YES inet6
4493+
inet6_c1_i YES inet6
4494+
inet4_c2_c YES inet4
4495+
inet4_c2_i YES inet4
4496+
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;
4497+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
4498+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4499+
inet4_c1_c NO inet6
4500+
inet6_c1_i NO inet6
4501+
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;
4502+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
4503+
COLUMN_NAME IS_NULLABLE COLUMN_TYPE
4504+
inet4_c1_c NO inet6
4505+
inet6_c1_i NO inet6
4506+
DROP TABLE t, t1, t2, t3, t4;
4507+
# End of 10.11 tests

mysql-test/main/func_hybrid_type.test

Lines changed: 103 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1164,3 +1164,106 @@ SELECT LEAST( CAST( 0 AS CHAR ), OLD_PASSWORD( 1 ) );
11641164
--echo #
11651165
--echo # End of 10.6 tests
11661166
--echo #
1167+
1168+
--echo #
1169+
--echo # MDEV-36581: COALESCE() returns nullable column while IFNULL() does not
1170+
--echo #
1171+
1172+
CREATE OR REPLACE VIEW test_coalesce_vs_ifnull AS
1173+
SELECT
1174+
COALESCE(operation_date, '1970-01-01 00:00:00') AS coalesced_date,
1175+
IFNULL(operation_date, '1970-01-01 00:00:00') AS ifnull_date
1176+
FROM (
1177+
SELECT NULL AS operation_date
1178+
) AS t;
1179+
1180+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE
1181+
FROM INFORMATION_SCHEMA.COLUMNS
1182+
WHERE TABLE_NAME = 'test_coalesce_vs_ifnull';
1183+
1184+
DROP VIEW test_coalesce_vs_ifnull;
1185+
1186+
# Tests on views
1187+
1188+
CREATE VIEW v2 as SELECT COALESCE(c, NULL) AS c_col, IFNULL(c, 10) AS i_col FROM (SELECT NULL AS c) AS t;
1189+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v2';
1190+
1191+
DROP VIEW v2;
1192+
1193+
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;
1194+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v3';
1195+
1196+
DROP VIEW v3;
1197+
1198+
CREATE VIEW v4 AS SELECT COALESCE(c, NULL, NULL) as c_col FROM (SELECT NULL AS c) AS t;
1199+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v4';
1200+
1201+
DROP VIEW v4;
1202+
1203+
CREATE VIEW v5 AS SELECT COALESCE(c, COALESCE(NULL, 10), NULL) as c_col FROM (SELECT NULL AS c) AS t;
1204+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'v5';
1205+
1206+
DROP VIEW v5;
1207+
1208+
# Tests on tables
1209+
1210+
CREATE TABLE t (c1 INT, c2 DOUBLE, c3 VARCHAR(5), c4 DATE);
1211+
INSERT INTO t values (1, 2.3, 'four', '2025-05-06');
1212+
1213+
--enable_metadata
1214+
--disable_ps_protocol
1215+
SELECT COALESCE(c1, 10) AS coalesced_c1, IFNULL(c1, 10) AS ifnull_c1 FROM t;
1216+
SELECT COALESCE(c1, NULL) AS coalesced_c1, IFNULL(c1, NULL) AS ifnull_c1 FROM t;
1217+
SELECT COALESCE(c2, NULL) AS coalesced_c2, IFNULL(c2, NULL) as ifnull_c2 FROM t;
1218+
SELECT COALESCE(c3, 'two') as coalesced_c1, COALESCE(c4, '2025-07-08') AS coalesced_date FROM t;
1219+
--enable_ps_protocol
1220+
--disable_metadata
1221+
1222+
INSERT INTO t values (2, 3.4, NULL, NULL);
1223+
--enable_metadata
1224+
--disable_ps_protocol
1225+
SELECT COALESCE(c3, 'two') AS coalesced_c3, IFNULL(c3, 'three') AS ifnull_c3 FROM t WHERE c1 = 2;
1226+
SELECT COALESCE(c3, 'four', NULL) AS coalesced_c3, COALESCE(COALESCE(c3, NULL), NULL) AS coalesced_c3_null FROM t WHERE c1 = 2;
1227+
SELECT COALESCE(c4, COALESCE('2025-05-06', NULL)) AS coalesced_date FROM t WHERE c1 = 2;
1228+
--enable_ps_protocol
1229+
--disable_metadata
1230+
1231+
DROP TABLE t;
1232+
1233+
# Case when one type cannot alwasy be converted to another safely
1234+
SET sql_mode='';
1235+
CREATE TABLE t1 (a UUID, b VARCHAR(32) NOT NULL);
1236+
INSERT INTO t1 VALUES (NULL, '1');
1237+
CREATE TABLE t2 AS SELECT COALESCE(a, b), IFNULL(a, b) FROM t1;
1238+
1239+
SHOW CREATE TABLE t2;
1240+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
1241+
1242+
DROP TABLE t1, t2;
1243+
1244+
CREATE TABLE t (c1 INET6, c2 INET4);
1245+
INSERT INTO t VALUES ('::', '0.0.0.0'), (NULL, NULL);
1246+
1247+
CREATE TABLE t1 AS
1248+
SELECT
1249+
COALESCE(c1, '::1') AS inet6_c1_c, IFNULL(c1, '::1') AS inet6_c1_i,
1250+
COALESCE(c2, '0.0.0.0') AS inet4_c2_c, IFNULL(c2, '0.0.0.0') AS inet4_c2_i
1251+
FROM t;
1252+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't1';
1253+
1254+
CREATE TABLE t2 AS
1255+
SELECT
1256+
COALESCE(c1, 'ipv6') AS inet6_c1_c, IFNULL(c1, 'ipv6') AS inet6_c1_i,
1257+
COALESCE(c2, 'ipv4') AS inet4_c2_c, IFNULL(c2, 'ipv4') AS inet4_c2_i
1258+
FROM t;
1259+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't2';
1260+
1261+
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;
1262+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
1263+
1264+
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;
1265+
SELECT COLUMN_NAME, IS_NULLABLE, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 't3';
1266+
1267+
DROP TABLE t, t1, t2, t3, t4;
1268+
1269+
--echo # End of 10.11 tests

mysql-test/main/gis.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -5014,8 +5014,8 @@ LEAST(POINT(1,1),0x60);
50145014
SHOW CREATE TABLE t1;
50155015
Table Create Table
50165016
t1 CREATE TABLE `t1` (
5017-
`COALESCE(0x60,POINT(1,1))` longblob DEFAULT NULL,
5018-
`COALESCE(POINT(1,1),0x60)` longblob DEFAULT NULL,
5017+
`COALESCE(0x60,POINT(1,1))` longblob NOT NULL,
5018+
`COALESCE(POINT(1,1),0x60)` longblob NOT NULL,
50195019
`LEAST(0x60,POINT(1,1))` longblob DEFAULT NULL,
50205020
`LEAST(POINT(1,1),0x60)` longblob DEFAULT NULL
50215021
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci

mysql-test/main/null.result

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -263,11 +263,11 @@ t1 CREATE TABLE `t1` (
263263
`c01` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
264264
`c02` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
265265
`c03` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
266-
`c04` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
266+
`c04` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
267267
`c05` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
268268
`c06` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
269-
`c07` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
270-
`c08` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
269+
`c07` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
270+
`c08` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci NOT NULL,
271271
`c09` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
272272
`c10` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,
273273
`c11` varchar(6) CHARACTER SET latin2 COLLATE latin2_general_ci DEFAULT NULL,

0 commit comments

Comments
 (0)