diff --git a/datatypes/mcs_datatype.h b/datatypes/mcs_datatype.h index 20a78c763..509f0a5f6 100644 --- a/datatypes/mcs_datatype.h +++ b/datatypes/mcs_datatype.h @@ -313,6 +313,18 @@ class SystemCatalog } } + bool isTemporal() const + { + switch (colDataType) + { + case datatypes::SystemCatalog::DATE: + case datatypes::SystemCatalog::DATETIME: + case datatypes::SystemCatalog::TIMESTAMP: + case datatypes::SystemCatalog::TIME: return true; + default: return false; + } + } + bool isSignedInteger() const { switch (colDataType) diff --git a/mysql-test/columnstore/basic/r/mcol-5963.result b/mysql-test/columnstore/basic/r/mcol-5963.result new file mode 100644 index 000000000..4f6e3b318 --- /dev/null +++ b/mysql-test/columnstore/basic/r/mcol-5963.result @@ -0,0 +1,130 @@ +DROP DATABASE IF EXISTS mcol5963; +CREATE DATABASE mcol5963; +USE mcol5963; +create table FOO(foo datetime) engine = columnstore; +insert into FOO(foo) values ('2025-08-27 15:26:25'); +select if(0 = 1, '2025-08-27 15:26:25', foo) from FOO; +if(0 = 1, '2025-08-27 15:26:25', foo) +2025-08-27 15:26:25 +select if(0 = 1, null, foo) from FOO; +if(0 = 1, null, foo) +2025-08-27 15:26:25 +select if(0 = 1, true, foo) from FOO; +if(0 = 1, true, foo) +2025-08-27 15:26:25 +select if(0 = 1, 5, foo) from FOO; +if(0 = 1, 5, foo) +2025-08-27 15:26:25 +select if(0 = 1, null, "text"); +if(0 = 1, null, "text") +text +drop table FOO; +create table FOO(foo datetime) engine = innodb; +insert into FOO(foo) values ('2025-08-27 15:26:25'); +select if(0 = 1, '2025-08-27 15:26:25', foo) from FOO; +if(0 = 1, '2025-08-27 15:26:25', foo) +2025-08-27 15:26:25 +select if(0 = 1, null, foo) from FOO; +if(0 = 1, null, foo) +2025-08-27 15:26:25 +select if(0 = 1, true, foo) from FOO; +if(0 = 1, true, foo) +2025-08-27 15:26:25 +select if(0 = 1, 5, foo) from FOO; +if(0 = 1, 5, foo) +2025-08-27 15:26:25 +select if(0 = 1, null, "text"); +if(0 = 1, null, "text") +text +drop table FOO; +create table FOO_DATE(foo date) engine = columnstore; +insert into FOO_DATE(foo) values ('2025-08-27'); +select if(0 = 1, true, foo) from FOO_DATE; +if(0 = 1, true, foo) +2025-08-27 +select if(0 = 1, 5, foo) from FOO_DATE; +if(0 = 1, 5, foo) +2025-08-27 +select if(0 = 1, null, foo) from FOO_DATE; +if(0 = 1, null, foo) +2025-08-27 +drop table FOO_DATE; +create table FOO_DATE(foo date) engine = innodb; +insert into FOO_DATE(foo) values ('2025-08-27'); +select if(0 = 1, true, foo) from FOO_DATE; +if(0 = 1, true, foo) +2025-08-27 +select if(0 = 1, 5, foo) from FOO_DATE; +if(0 = 1, 5, foo) +2025-08-27 +select if(0 = 1, null, foo) from FOO_DATE; +if(0 = 1, null, foo) +2025-08-27 +drop table FOO_DATE; +create table FOO_TIME(foo time) engine = columnstore; +insert into FOO_TIME(foo) values ('15:26:25'); +select if(0 = 1, true, foo) from FOO_TIME; +if(0 = 1, true, foo) +15:26:25 +select if(0 = 1, 5, foo) from FOO_TIME; +if(0 = 1, 5, foo) +15:26:25 +select if(0 = 1, null, foo) from FOO_TIME; +if(0 = 1, null, foo) +15:26:25 +drop table FOO_TIME; +create table FOO_TIME(foo time) engine = innodb; +insert into FOO_TIME(foo) values ('15:26:25'); +select if(0 = 1, true, foo) from FOO_TIME; +if(0 = 1, true, foo) +15:26:25 +select if(0 = 1, 5, foo) from FOO_TIME; +if(0 = 1, 5, foo) +15:26:25 +select if(0 = 1, null, foo) from FOO_TIME; +if(0 = 1, null, foo) +15:26:25 +drop table FOO_TIME; +create table FOO_TS(foo timestamp) engine = columnstore; +insert into FOO_TS(foo) values ('2025-08-27 15:26:25'); +select if(0 = 1, true, foo) from FOO_TS; +if(0 = 1, true, foo) +2025-08-27 15:26:25 +select if(0 = 1, 5, foo) from FOO_TS; +if(0 = 1, 5, foo) +2025-08-27 15:26:25 +select if(0 = 1, null, foo) from FOO_TS; +if(0 = 1, null, foo) +2025-08-27 15:26:25 +drop table FOO_TS; +create table FOO_TS(foo timestamp) engine = innodb; +insert into FOO_TS(foo) values ('2025-08-27 15:26:25'); +select if(0 = 1, true, foo) from FOO_TS; +if(0 = 1, true, foo) +2025-08-27 15:26:25 +select if(0 = 1, 5, foo) from FOO_TS; +if(0 = 1, 5, foo) +2025-08-27 15:26:25 +select if(0 = 1, null, foo) from FOO_TS; +if(0 = 1, null, foo) +2025-08-27 15:26:25 +drop table FOO_TS; +create table FOO(foo varchar(30)) engine = columnstore; +insert into FOO(foo) values ("text1"); +select if(0 = 1, true, foo) from FOO; +if(0 = 1, true, foo) +text1 +select if(0 = 1, NULL, foo) from FOO; +if(0 = 1, NULL, foo) +text1 +drop table FOO; +create table FOO(foo int) engine = columnstore; +insert into FOO(foo) values (123); +select if(0 = 1, true, foo) from FOO; +if(0 = 1, true, foo) +123 +select if(0 = 1, NULL, foo) from FOO; +if(0 = 1, NULL, foo) +123 +drop table FOO; +DROP DATABASE mcol5963; diff --git a/mysql-test/columnstore/basic/t/mcol-5963.test b/mysql-test/columnstore/basic/t/mcol-5963.test new file mode 100644 index 000000000..eff857db9 --- /dev/null +++ b/mysql-test/columnstore/basic/t/mcol-5963.test @@ -0,0 +1,110 @@ +-- source ../include/have_columnstore.inc +-- source include/have_innodb.inc + +--disable_warnings +DROP DATABASE IF EXISTS mcol5963; +--enable_warnings + +CREATE DATABASE mcol5963; + +USE mcol5963; + +create table FOO(foo datetime) engine = columnstore; +insert into FOO(foo) values ('2025-08-27 15:26:25'); + +select if(0 = 1, '2025-08-27 15:26:25', foo) from FOO; +select if(0 = 1, null, foo) from FOO; +select if(0 = 1, true, foo) from FOO; +select if(0 = 1, 5, foo) from FOO; +select if(0 = 1, null, "text"); + +drop table FOO; + +# InnoDB comparison for DATETIME +create table FOO(foo datetime) engine = innodb; +insert into FOO(foo) values ('2025-08-27 15:26:25'); + +select if(0 = 1, '2025-08-27 15:26:25', foo) from FOO; +select if(0 = 1, null, foo) from FOO; +select if(0 = 1, true, foo) from FOO; +select if(0 = 1, 5, foo) from FOO; +select if(0 = 1, null, "text"); + +drop table FOO; + +# Additional temporal types: DATE +create table FOO_DATE(foo date) engine = columnstore; +insert into FOO_DATE(foo) values ('2025-08-27'); + +select if(0 = 1, true, foo) from FOO_DATE; +select if(0 = 1, 5, foo) from FOO_DATE; +select if(0 = 1, null, foo) from FOO_DATE; + +drop table FOO_DATE; + +# InnoDB comparison for DATE +create table FOO_DATE(foo date) engine = innodb; +insert into FOO_DATE(foo) values ('2025-08-27'); + +select if(0 = 1, true, foo) from FOO_DATE; +select if(0 = 1, 5, foo) from FOO_DATE; +select if(0 = 1, null, foo) from FOO_DATE; + +drop table FOO_DATE; + +# Additional temporal types: TIME + +create table FOO_TIME(foo time) engine = columnstore; +insert into FOO_TIME(foo) values ('15:26:25'); + +select if(0 = 1, true, foo) from FOO_TIME; +select if(0 = 1, 5, foo) from FOO_TIME; +select if(0 = 1, null, foo) from FOO_TIME; +drop table FOO_TIME; + +# InnoDB comparison for TIME +create table FOO_TIME(foo time) engine = innodb; +insert into FOO_TIME(foo) values ('15:26:25'); + +select if(0 = 1, true, foo) from FOO_TIME; +select if(0 = 1, 5, foo) from FOO_TIME; +select if(0 = 1, null, foo) from FOO_TIME; + +drop table FOO_TIME; + +# Additional temporal types: TIMESTAMP +create table FOO_TS(foo timestamp) engine = columnstore; + +insert into FOO_TS(foo) values ('2025-08-27 15:26:25'); +select if(0 = 1, true, foo) from FOO_TS; +select if(0 = 1, 5, foo) from FOO_TS; +select if(0 = 1, null, foo) from FOO_TS; + +drop table FOO_TS; + +# InnoDB comparison for TIMESTAMP +create table FOO_TS(foo timestamp) engine = innodb; +insert into FOO_TS(foo) values ('2025-08-27 15:26:25'); + +select if(0 = 1, true, foo) from FOO_TS; +select if(0 = 1, 5, foo) from FOO_TS; +select if(0 = 1, null, foo) from FOO_TS; + +drop table FOO_TS; + +create table FOO(foo varchar(30)) engine = columnstore; +insert into FOO(foo) values ("text1"); + +select if(0 = 1, true, foo) from FOO; +select if(0 = 1, NULL, foo) from FOO; + +drop table FOO; + +create table FOO(foo int) engine = columnstore; +insert into FOO(foo) values (123); + +select if(0 = 1, true, foo) from FOO; +select if(0 = 1, NULL, foo) from FOO; + +drop table FOO; +DROP DATABASE mcol5963; diff --git a/utils/funcexp/func_if.cpp b/utils/funcexp/func_if.cpp index 0c37c6b48..8f7435c19 100644 --- a/utils/funcexp/func_if.cpp +++ b/utils/funcexp/func_if.cpp @@ -28,6 +28,7 @@ using namespace std; #include "functor_all.h" #include "functioncolumn.h" #include "predicateoperator.h" +#include "constantcolumn.h" using namespace execplan; #include "rowgroup.h" @@ -124,9 +125,58 @@ CalpontSystemCatalog::ColType Func_if::operationType(FunctionParm& fp, return ct; } - CalpontSystemCatalog::ColType ct = fp[1]->data()->resultType(); + // Special handling: if one branch is a NULL constant and the other is a temporal type, + // the result type must be that temporal type. Otherwise PredicateOperator might promote + // to a non-temporal type causing zero-date conversions. + auto chooseTemporalIfOtherIsNull = [](const CalpontSystemCatalog::ColType& other, + bool maybeNullIsNullConst, + CalpontSystemCatalog::ColType& out) -> bool { + if (!maybeNullIsNullConst) + return false; + out = other; + return other.isTemporal(); + }; + + bool isNullConst1 = false, isNullConst2 = false; + if (auto cc1 = dynamic_cast(fp[1]->data())) + { + isNullConst1 = cc1->isNull(); + } + if (auto cc2 = dynamic_cast(fp[2]->data())) + { + isNullConst2 = cc2->isNull(); + } + + auto rt1 = fp[1]->data()->resultType(); + auto rt2 = fp[2]->data()->resultType(); + + CalpontSystemCatalog::ColType chosen; + if (chooseTemporalIfOtherIsNull(rt2, isNullConst1, chosen)) + { + resultType = chosen; + return chosen; + } + if (chooseTemporalIfOtherIsNull(rt1, isNullConst2, chosen)) + { + resultType = chosen; + return chosen; + } + + // If exactly one side is temporal and the other side is not string, prefer temporal type. + if (rt1.isTemporal() && !rt2.isTemporal() && !datatypes::isCharType(rt2.colDataType)) + { + resultType = rt1; + return rt1; + } + if (rt2.isTemporal() && !rt1.isTemporal() && !datatypes::isCharType(rt1.colDataType)) + { + resultType = rt2; + return rt2; + } + PredicateOperator op; - op.setOpType(ct, fp[2]->data()->resultType()); + op.setOpType(rt1, rt2); + CalpontSystemCatalog::ColType ct; ct = op.operationType(); resultType = ct; return ct;