From 74f81f758adbd8522e9ba2da4357e556153e0f10 Mon Sep 17 00:00:00 2001 From: YANGGMM Date: Thu, 11 Jul 2024 23:24:55 +0800 Subject: [PATCH] fix makedate and last_day func (#1.2-dev) (#17473) fix makedate and last_day func Approved by: @m-schen, @ouyuanning, @heni02, @sukki37 --- pkg/sql/plan/base_binder.go | 8 ++ pkg/sql/plan/function/func_binary.go | 28 +++-- pkg/sql/plan/function/func_binary_test.go | 26 +++++ .../cases/function/func_last_day.result | 96 ++++++++++++++++ .../cases/function/func_last_day.sql | 37 +++++++ .../cases/function/func_make_date.result | 104 ++++++++++++++++++ .../cases/function/func_make_date.sql | 38 +++++++ 7 files changed, 330 insertions(+), 7 deletions(-) diff --git a/pkg/sql/plan/base_binder.go b/pkg/sql/plan/base_binder.go index fdebd8afd60f9..b2b16a72dd4f6 100644 --- a/pkg/sql/plan/base_binder.go +++ b/pkg/sql/plan/base_binder.go @@ -1582,6 +1582,14 @@ func BindFuncExprImplByPlanExpr(ctx context.Context, name string, args []*Expr) return newExpr, nil } + case "last_day": + if len(args) != 1 { + return nil, moerr.NewInvalidArg(ctx, name+" function have invalid input args length", len(args)) + } + case "makedate": + if len(args) != 2 { + return nil, moerr.NewInvalidArg(ctx, name+" function have invalid input args length", len(args)) + } } // get args(exprs) & types diff --git a/pkg/sql/plan/function/func_binary.go b/pkg/sql/plan/function/func_binary.go index 761fb50e5bd65..5e743c9f0474e 100644 --- a/pkg/sql/plan/function/func_binary.go +++ b/pkg/sql/plan/function/func_binary.go @@ -2640,19 +2640,25 @@ func MakeDateString( } } else { // null - year, err := strconv.ParseInt(functionUtil.QuickBytesToStr(yearStr), 10, 64) + yearStrStr := functionUtil.QuickBytesToStr(yearStr) + year, err := strconv.ParseInt(yearStrStr, 10, 64) if err != nil { - if err := rs.AppendBytes(nil, true); err != nil { - return err + yearFloat, err := strconv.ParseFloat(yearStrStr, 64) + if err != nil { + year = castBinaryArrayToInt(yearStr) + } else { + year = int64(yearFloat) } - continue } day, err := strconv.ParseInt(functionUtil.QuickBytesToStr(dayStr), 10, 64) if err != nil { - if err := rs.AppendBytes(nil, true); err != nil { - return err + // parse as float64 + dayFloat, err := strconv.ParseFloat(functionUtil.QuickBytesToStr(dayStr), 64) + if err != nil { + day = castBinaryArrayToInt(dayStr) + } else { + day = int64(dayFloat) } - continue } if day <= 0 || year < 0 || year > 9999 { if err := rs.AppendBytes(nil, true); err != nil { @@ -2968,3 +2974,11 @@ func CosineDistanceArray[T types.RealNumbers](ivecs []*vector.Vector, result vec return moarray.CosineDistance[T](_v1, _v2) }) } + +func castBinaryArrayToInt(array []uint8) int64 { + var result int64 + for i, value := range array { + result += int64(value) << uint(8*(len(array)-i-1)) + } + return result +} diff --git a/pkg/sql/plan/function/func_binary_test.go b/pkg/sql/plan/function/func_binary_test.go index bec4b01dd6d59..7b91a9d33cc66 100644 --- a/pkg/sql/plan/function/func_binary_test.go +++ b/pkg/sql/plan/function/func_binary_test.go @@ -3228,3 +3228,29 @@ func TestSplitPart(t *testing.T) { require.True(t, s, fmt.Sprintf("case is '%s', err info is '%s'", tc.info, info)) } } + +func Test_castBinaryArrayToInt(t *testing.T) { + testCases := []struct { + name string + input []uint8 + expect int64 + }{ + { + name: "test1", + input: []uint8{7, 229}, + expect: 2021, + }, + { + name: "test2", + input: []uint8{8, 45}, + expect: 2093, + }, + } + + for _, tc := range testCases { + t.Run(tc.name, func(t *testing.T) { + result := castBinaryArrayToInt(tc.input) + require.Equal(t, tc.expect, result) + }) + } +} diff --git a/test/distributed/cases/function/func_last_day.result b/test/distributed/cases/function/func_last_day.result index adf52473190dd..288e59b2a2353 100644 --- a/test/distributed/cases/function/func_last_day.result +++ b/test/distributed/cases/function/func_last_day.result @@ -63,3 +63,99 @@ null SELECT LAST_DAY('2024-02-01 23:61:01'); LAST_DAY(2024-02-01 23:61:01) null +SELECT LAST_DAY('2003-02-05'); +LAST_DAY(2003-02-05) +2003-02-28 +SELECT LAST_DAY('2004-02-05'); +LAST_DAY(2004-02-05) +2004-02-29 +SELECT LAST_DAY('2004-01-01 01:01:01'); +LAST_DAY(2004-01-01 01:01:01) +2004-01-31 +SELECT LAST_DAY('2003-03-32'); +LAST_DAY(2003-03-32) +null +SELECT LAST_DAY('2003-02-30'); +LAST_DAY(2003-02-30) +null +SELECT LAST_DAY('2024-13-01 01:01:01'); +LAST_DAY(2024-13-01 01:01:01) +null +SELECT LAST_DAY('2024-02-99 23:01:01'); +LAST_DAY(2024-02-99 23:01:01) +null +SELECT LAST_DAY('2024-02-01 23:01:61'); +LAST_DAY(2024-02-01 23:01:61) +null +SELECT LAST_DAY('2024-02-01 24:01:01'); +LAST_DAY(2024-02-01 24:01:01) +null +SELECT LAST_DAY('2024-02-01 25:01:01'); +LAST_DAY(2024-02-01 25:01:01) +null +SELECT LAST_DAY('2024-02-01 23:61:01'); +LAST_DAY(2024-02-01 23:61:01) +null +SELECT LAST_DAY('2024-02-01 23:61:AA'); +LAST_DAY(2024-02-01 23:61:AA) +null +SELECT LAST_DAY('20240603'); +LAST_DAY(20240603) +2024-06-30 +SELECT LAST_DAY('hello'); +LAST_DAY(hello) +null +SELECT LAST_DAY(); +invalid argument last_day function have invalid input args length, bad value 0 +SELECT LAST_DAY(MAKEDATE(2024, 100)); +LAST_DAY(MAKEDATE(2024, 100)) +2024-04-30 +SELECT LAST_DAY(CURDATE()); +LAST_DAY(CURDATE()) +2024-07-31 +SELECT LAST_DAY(NOW()); +LAST_DAY(NOW()) +2024-07-31 +SELECT LAST_DAY(DATE_SUB('1991-01-01', INTERVAL 1 MONTH)) AS last_day_of_previous_month; +last_day_of_previous_month +1990-12-31 +SELECT LAST_DAY(20240601); +LAST_DAY(20240601) +2024-06-30 +SELECT LAST_DAY(2024-06-01); +LAST_DAY(2024 - 6 - 1) +null +SELECT LAST_DAY(0b11111100101); +LAST_DAY(0b11111100101) +null +SELECT LAST_DAY(0x82d); +LAST_DAY(0x82d) +null +SELECT LAST_DAY('0001-12-30'); +LAST_DAY(0001-12-30) +0001-12-31 +SELECT LAST_DAY('9999-01-30'); +LAST_DAY(9999-01-30) +9999-01-31 +SELECT LAST_DAY('0213-04-30'); +LAST_DAY(0213-04-30) +0213-04-30 +SELECT LAST_DAY(NULL); +LAST_DAY(null) +null +SELECT LAST_DAY('2024-06-30', 123); +invalid argument last_day function have invalid input args length, bad value 2 +SELECT LAST_DAY('2024-06-30', ''); +invalid argument last_day function have invalid input args length, bad value 2 +SELECT LAST_DAY(''); +LAST_DAY() +null +SELECT LAST_DAY(0x134d9a1); +LAST_DAY(0x134d9a1) +null +SELECT LAST_DAY(0b1001101001101100110100001); +LAST_DAY(0b1001101001101100110100001) +null +SELECT LAST_DAY(9898088989808980890808980809808); +LAST_DAY(9898088989808980890808980809808) +null diff --git a/test/distributed/cases/function/func_last_day.sql b/test/distributed/cases/function/func_last_day.sql index 269adfebf2128..e94917584e550 100644 --- a/test/distributed/cases/function/func_last_day.sql +++ b/test/distributed/cases/function/func_last_day.sql @@ -37,3 +37,40 @@ SELECT LAST_DAY('2024-02-01 23:01:61'); SELECT LAST_DAY('2024-02-01 24:01:01'); SELECT LAST_DAY('2024-02-01 25:01:01'); SELECT LAST_DAY('2024-02-01 23:61:01'); + + +SELECT LAST_DAY('2003-02-05'); +SELECT LAST_DAY('2004-02-05'); +SELECT LAST_DAY('2004-01-01 01:01:01'); +SELECT LAST_DAY('2003-03-32'); +SELECT LAST_DAY('2003-02-30'); +SELECT LAST_DAY('2024-13-01 01:01:01'); +SELECT LAST_DAY('2024-02-99 23:01:01'); +SELECT LAST_DAY('2024-02-01 23:01:61'); +SELECT LAST_DAY('2024-02-01 24:01:01'); +SELECT LAST_DAY('2024-02-01 25:01:01'); +SELECT LAST_DAY('2024-02-01 23:61:01'); +SELECT LAST_DAY('2024-02-01 23:61:AA'); +SELECT LAST_DAY('20240603'); +SELECT LAST_DAY('hello'); +SELECT LAST_DAY(); +SELECT LAST_DAY(MAKEDATE(2024, 100)); +-- @ignore:0 +SELECT LAST_DAY(CURDATE()); +-- @ignore:0 +SELECT LAST_DAY(NOW()); +SELECT LAST_DAY(DATE_SUB('1991-01-01', INTERVAL 1 MONTH)) AS last_day_of_previous_month; +SELECT LAST_DAY(20240601); +SELECT LAST_DAY(2024-06-01); +SELECT LAST_DAY(0b11111100101); +SELECT LAST_DAY(0x82d); +SELECT LAST_DAY('0001-12-30'); +SELECT LAST_DAY('9999-01-30'); +SELECT LAST_DAY('0213-04-30'); +SELECT LAST_DAY(NULL); +SELECT LAST_DAY('2024-06-30', 123); +SELECT LAST_DAY('2024-06-30', ''); +SELECT LAST_DAY(''); +SELECT LAST_DAY(0x134d9a1); +SELECT LAST_DAY(0b1001101001101100110100001); +SELECT LAST_DAY(9898088989808980890808980809808); diff --git a/test/distributed/cases/function/func_make_date.result b/test/distributed/cases/function/func_make_date.result index e3c307c83c23c..35ac691140fee 100644 --- a/test/distributed/cases/function/func_make_date.result +++ b/test/distributed/cases/function/func_make_date.result @@ -89,3 +89,107 @@ null SELECT MAKEDATE(2024, ''); MAKEDATE(2024, ) null +SELECT MAKEDATE(0, 0); +MAKEDATE(0, 0) +null +SELECT MAKEDATE(0, 123); +MAKEDATE(0, 123) +2000-05-02 +SELECT MAKEDATE(2024, 99); +MAKEDATE(2024, 99) +2024-04-08 +SELECT MAKEDATE(2024, 366); +MAKEDATE(2024, 366) +2024-12-31 +SELECT MAKEDATE(2024, 367); +MAKEDATE(2024, 367) +2025-01-01 +SELECT MAKEDATE(2024, -399); +MAKEDATE(2024, -399) +null +SELECT MAKEDATE(2055, 0); +MAKEDATE(2055, 0) +null +SELECT MAKEDATE(2055, '10'); +MAKEDATE(2055, 10) +2055-01-10 +SELECT MAKEDATE(2055, '010'); +MAKEDATE(2055, 010) +2055-01-10 +SELECT MAKEDATE(2832, 088); +MAKEDATE(2832, 88) +2832-03-28 +SELECT MAKEDATE(2832, 0A88); +invalid input: column 0a88 does not exist +SELECT MAKEDATE(2832, '0A88'); +MAKEDATE(2832, 0A88) +null +SELECT MAKEDATE(2024, 1.2); +MAKEDATE(2024, 1.2) +2024-01-01 +SELECT MAKEDATE(2024, 300.1234890); +MAKEDATE(2024, 300.1234890) +2024-10-26 +SELECT MAKEDATE(YEAR('2011-01-09'), 10.456); +MAKEDATE(YEAR(2011-01-09), 10.456) +2011-01-10 +SELECT MAKEDATE(YEAR(NOW()), -2); +MAKEDATE(YEAR(NOW()), -2) +null +SELECT MAKEDATE(YEAR(NOW()), 2); +MAKEDATE(YEAR(NOW()), 2) +2024-01-02 +SELECT MAKEDATE(20244, 123); +MAKEDATE(20244, 123) +null +SELECT MAKEDATE(0123, 123); +MAKEDATE(123, 123) +0123-05-03 +SELECT MAKEDATE(0000, 123); +MAKEDATE(0, 123) +2000-05-02 +SELECT MAKEDATE(0001, 123); +MAKEDATE(1, 123) +2001-05-03 +SELECT MAKEDATE(0042, 321); +MAKEDATE(42, 321) +2042-11-17 +SELECT MAKEDATE('2024', 321); +MAKEDATE(2024, 321) +2024-11-16 +SELECT MAKEDATE('2x23', 321); +MAKEDATE(2x23, 321) +null +SELECT MAKEDATE(0b11111100101, 123); +MAKEDATE(0b11111100101, 123) +2021-05-03 +SELECT MAKEDATE(0x82d, 123); +MAKEDATE(0x82d, 123) +2093-05-03 +SELECT MAKEDATE(NULL, 123); +MAKEDATE(null, 123) +null +SELECT MAKEDATE(NULL, NULL); +MAKEDATE(null, null) +null +SELECT MAKEDATE(2024, NULL); +MAKEDATE(2024, null) +null +SELECT MAKEDATE(2024, ''); +MAKEDATE(2024, ) +null +SELECT MAKEDATE(2024, 2913174); +MAKEDATE(2024, 2913174) +9999-12-31 +SELECT MAKEDATE(2024, 2913175); +MAKEDATE(2024, 2913175) +null +SELECT MAKEDATE(2024, 29131750000); +MAKEDATE(2024, 29131750000) +null +SELECT MAKEDATE(29131750000, 2024); +MAKEDATE(29131750000, 2024) +null +SELECT MAKEDATE(29131750000111111111, 2024); +MAKEDATE(29131750000111111111, 2024) +null diff --git a/test/distributed/cases/function/func_make_date.sql b/test/distributed/cases/function/func_make_date.sql index d854c694e53af..95fc6ab7759bc 100644 --- a/test/distributed/cases/function/func_make_date.sql +++ b/test/distributed/cases/function/func_make_date.sql @@ -56,3 +56,41 @@ SELECT MAKEDATE(29131750000111111111, 2024); SELECT MAKEDATE('2x23', 321); SELECT MAKEDATE(2024, ''); + +SELECT MAKEDATE(0, 0); +SELECT MAKEDATE(0, 123); +SELECT MAKEDATE(2024, 99); +SELECT MAKEDATE(2024, 366); +SELECT MAKEDATE(2024, 367); +SELECT MAKEDATE(2024, -399); +SELECT MAKEDATE(2055, 0); +SELECT MAKEDATE(2055, '10'); +SELECT MAKEDATE(2055, '010'); +SELECT MAKEDATE(2832, 088); +SELECT MAKEDATE(2832, 0A88); +SELECT MAKEDATE(2832, '0A88'); +SELECT MAKEDATE(2024, 1.2); +SELECT MAKEDATE(2024, 300.1234890); +SELECT MAKEDATE(YEAR('2011-01-09'), 10.456); +-- @ignore:0 +SELECT MAKEDATE(YEAR(NOW()), -2); +-- @ignore:0 +SELECT MAKEDATE(YEAR(NOW()), 2); +SELECT MAKEDATE(20244, 123); +SELECT MAKEDATE(0123, 123); +SELECT MAKEDATE(0000, 123); +SELECT MAKEDATE(0001, 123); +SELECT MAKEDATE(0042, 321); +SELECT MAKEDATE('2024', 321); +SELECT MAKEDATE('2x23', 321); +SELECT MAKEDATE(0b11111100101, 123); +SELECT MAKEDATE(0x82d, 123); +SELECT MAKEDATE(NULL, 123); +SELECT MAKEDATE(NULL, NULL); +SELECT MAKEDATE(2024, NULL); +SELECT MAKEDATE(2024, ''); +SELECT MAKEDATE(2024, 2913174); +SELECT MAKEDATE(2024, 2913175); +SELECT MAKEDATE(2024, 29131750000); +SELECT MAKEDATE(29131750000, 2024); +SELECT MAKEDATE(29131750000111111111, 2024);