Skip to content

Commit 56cea82

Browse files
montywiabarkov
authored andcommitted
MDEV-20023 Implement Oracle TRUNC() function
The following Oracle formats are supported: Truncate to day: DD, DDD,J Truncate to month: MM,MON,MONTH,RM Truncate to Year: SYEAR,SYYYY,Y,YEAR,YY,YYY,YYYY TRUNC(date) is same as TRUNC(date, "MM")
1 parent 893761b commit 56cea82

File tree

9 files changed

+390
-15
lines changed

9 files changed

+390
-15
lines changed

include/my_time.h

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -176,9 +176,18 @@ double TIME_to_double(const MYSQL_TIME *my_time);
176176
int check_time_range(struct st_mysql_time *my_time, uint dec, int *warning);
177177
my_bool check_datetime_range(const MYSQL_TIME *ltime);
178178

179+
/*
180+
Accurate only for the past couple of centuries.
181+
Also works with 2 digit year 01-99 (1971-2069)
182+
Year 0 is ignored as MariaDB uses year 0 as 'not specifed'. This
183+
matches how things how leap year was calculated in calc_days_in_year().
184+
*/
185+
186+
#define isleap(y) (((y) & 3) == 0 && (((y) % 100) != 0 || (((y) % 400) == 0 && y != 0)))
179187

180188
long calc_daynr(uint year,uint month,uint day);
181189
uint calc_days_in_year(uint year);
190+
uint calc_days_in_month(uint year, uint month);
182191
uint year_2000_handling(uint year);
183192

184193
void my_init_time(void);
Lines changed: 122 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,122 @@
1+
# Test for function trunc()
2+
#
3+
# Simple test
4+
#
5+
select trunc("2025-07-27 12:01:02.123");
6+
trunc("2025-07-27 12:01:02.123")
7+
2025-07-27
8+
select trunc("2025-07-27 12:01:02.123","YY");
9+
trunc("2025-07-27 12:01:02.123","YY")
10+
2025-01-01
11+
select trunc("2025-07-27 12:01:02.123","MM");
12+
trunc("2025-07-27 12:01:02.123","MM")
13+
2025-07-01
14+
select trunc("2025-07-27 12:01:02.123","DD");
15+
trunc("2025-07-27 12:01:02.123","DD")
16+
2025-07-27
17+
select trunc("hello");
18+
trunc("hello")
19+
NULL
20+
Warnings:
21+
Warning 1292 Incorrect datetime value: 'hello'
22+
select trunc(1);
23+
trunc(1)
24+
NULL
25+
Warnings:
26+
Warning 1292 Incorrect datetime value: '1'
27+
# Ensure that trunc table name and column can still be used
28+
create table trunc (trunc int);
29+
insert into trunc (trunc) values (1);
30+
select trunc from trunc;
31+
trunc
32+
1
33+
drop table trunc;
34+
#
35+
# Test all format variations
36+
#
37+
CREATE TABLE t1(c2 datetime, c3 date, c4 timestamp);
38+
INSERT INTO t1 VALUES ('2021-11-12 00:23:12', '2021-11-12', '2021-11-12 00:23:12');
39+
INSERT INTO t1 VALUES ('0000-09-02 00:00:00', '0000-09-02', '1980-09-02 00:00:00');
40+
INSERT INTO t1 VALUES ('9999-09-02', '9999-09-02', '1980-09-02');
41+
create table t2 (format varchar(5)) engine=aria;
42+
insert into t2 values ("DD"),("DDD"),("J"),("MM"),("MON"),("MONTH"),("RM"),("SYEAR"),("SYYYY"),("Y"),("YEAR"),("YY"),("YYY"),("YYYY"), ("ZZZ");
43+
SELECT format,trunc(c2,format),trunc(c3,format),trunc(c4,format) from t2 straight_join t1;
44+
format trunc(c2,format) trunc(c3,format) trunc(c4,format)
45+
DD 2021-11-12 2021-11-12 2021-11-12
46+
DDD 2021-11-12 2021-11-12 2021-11-12
47+
J 2021-11-12 2021-11-12 2021-11-12
48+
MM 2021-11-01 2021-11-01 2021-11-01
49+
MON 2021-11-01 2021-11-01 2021-11-01
50+
MONTH 2021-11-01 2021-11-01 2021-11-01
51+
RM 2021-11-01 2021-11-01 2021-11-01
52+
SYEAR 2021-01-01 2021-01-01 2021-01-01
53+
SYYYY 2021-01-01 2021-01-01 2021-01-01
54+
Y 2021-01-01 2021-01-01 2021-01-01
55+
YEAR 2021-01-01 2021-01-01 2021-01-01
56+
YY 2021-01-01 2021-01-01 2021-01-01
57+
YYY 2021-01-01 2021-01-01 2021-01-01
58+
YYYY 2021-01-01 2021-01-01 2021-01-01
59+
ZZZ NULL NULL NULL
60+
DD 0000-09-02 0000-09-02 1980-09-02
61+
DDD 0000-09-02 0000-09-02 1980-09-02
62+
J 0000-09-02 0000-09-02 1980-09-02
63+
MM 0000-09-01 0000-09-01 1980-09-01
64+
MON 0000-09-01 0000-09-01 1980-09-01
65+
MONTH 0000-09-01 0000-09-01 1980-09-01
66+
RM 0000-09-01 0000-09-01 1980-09-01
67+
SYEAR 0000-01-01 0000-01-01 1980-01-01
68+
SYYYY 0000-01-01 0000-01-01 1980-01-01
69+
Y 0000-01-01 0000-01-01 1980-01-01
70+
YEAR 0000-01-01 0000-01-01 1980-01-01
71+
YY 0000-01-01 0000-01-01 1980-01-01
72+
YYY 0000-01-01 0000-01-01 1980-01-01
73+
YYYY 0000-01-01 0000-01-01 1980-01-01
74+
ZZZ NULL NULL NULL
75+
DD 9999-09-02 9999-09-02 1980-09-02
76+
DDD 9999-09-02 9999-09-02 1980-09-02
77+
J 9999-09-02 9999-09-02 1980-09-02
78+
MM 9999-09-01 9999-09-01 1980-09-01
79+
MON 9999-09-01 9999-09-01 1980-09-01
80+
MONTH 9999-09-01 9999-09-01 1980-09-01
81+
RM 9999-09-01 9999-09-01 1980-09-01
82+
SYEAR 9999-01-01 9999-01-01 1980-01-01
83+
SYYYY 9999-01-01 9999-01-01 1980-01-01
84+
Y 9999-01-01 9999-01-01 1980-01-01
85+
YEAR 9999-01-01 9999-01-01 1980-01-01
86+
YY 9999-01-01 9999-01-01 1980-01-01
87+
YYY 9999-01-01 9999-01-01 1980-01-01
88+
YYYY 9999-01-01 9999-01-01 1980-01-01
89+
ZZZ NULL NULL NULL
90+
Warnings:
91+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
92+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
93+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
94+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
95+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
96+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
97+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
98+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
99+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
100+
#
101+
# Test wrong usage
102+
#
103+
select trunc('2021-11-12 00:23:12',"");
104+
trunc('2021-11-12 00:23:12',"")
105+
NULL
106+
Warnings:
107+
Warning 1292 Incorrect TRUNC value: ''
108+
select trunc("","DD");
109+
trunc("","DD")
110+
NULL
111+
Warnings:
112+
Warning 1292 Incorrect datetime value: ''
113+
select trunc();
114+
ERROR 42000: Incorrect parameter count in the call to native function 'trunc'
115+
select trunc(1);
116+
trunc(1)
117+
NULL
118+
Warnings:
119+
Warning 1292 Incorrect datetime value: '1'
120+
select trunc(1,2,3);
121+
ERROR 42000: Incorrect parameter count in the call to native function 'trunc'
122+
drop table t1,t2;
Lines changed: 48 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,48 @@
1+
--echo # Test for function trunc()
2+
3+
--echo #
4+
--echo # Simple test
5+
--echo #
6+
7+
select trunc("2025-07-27 12:01:02.123");
8+
select trunc("2025-07-27 12:01:02.123","YY");
9+
select trunc("2025-07-27 12:01:02.123","MM");
10+
select trunc("2025-07-27 12:01:02.123","DD");
11+
12+
select trunc("hello");
13+
select trunc(1);
14+
15+
--echo # Ensure that trunc table name and column can still be used
16+
17+
create table trunc (trunc int);
18+
insert into trunc (trunc) values (1);
19+
select trunc from trunc;
20+
drop table trunc;
21+
22+
--echo #
23+
--echo # Test all format variations
24+
--echo #
25+
26+
CREATE TABLE t1(c2 datetime, c3 date, c4 timestamp);
27+
INSERT INTO t1 VALUES ('2021-11-12 00:23:12', '2021-11-12', '2021-11-12 00:23:12');
28+
INSERT INTO t1 VALUES ('0000-09-02 00:00:00', '0000-09-02', '1980-09-02 00:00:00');
29+
INSERT INTO t1 VALUES ('9999-09-02', '9999-09-02', '1980-09-02');
30+
31+
create table t2 (format varchar(5)) engine=aria;
32+
insert into t2 values ("DD"),("DDD"),("J"),("MM"),("MON"),("MONTH"),("RM"),("SYEAR"),("SYYYY"),("Y"),("YEAR"),("YY"),("YYY"),("YYYY"), ("ZZZ");
33+
34+
SELECT format,trunc(c2,format),trunc(c3,format),trunc(c4,format) from t2 straight_join t1;
35+
36+
--echo #
37+
--echo # Test wrong usage
38+
--echo #
39+
40+
select trunc('2021-11-12 00:23:12',"");
41+
select trunc("","DD");
42+
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
43+
select trunc();
44+
select trunc(1);
45+
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
46+
select trunc(1,2,3);
47+
48+
drop table t1,t2;

sql-common/my_time.c

Lines changed: 11 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -50,14 +50,22 @@ uchar days_in_month[]= {31, 28, 31, 30, 31, 30, 31, 31, 30, 31, 30, 31, 0};
5050
static long my_time_zone=0;
5151

5252

53-
/* Calc days in one year. works with 0 <= year <= 99 */
53+
/* Calc days in one year */
5454

5555
uint calc_days_in_year(uint year)
5656
{
57-
return ((year & 3) == 0 && (year%100 || (year%400 == 0 && year)) ?
58-
366 : 365);
57+
return isleap(year) ? 366 : 365;
5958
}
6059

60+
/* Calc days in a month */
61+
62+
uint calc_days_in_month(uint year, uint month)
63+
{
64+
uint days= days_in_month[month-1];
65+
if (month == 2 && isleap(year))
66+
days= 29;
67+
return days;
68+
}
6169

6270
#ifdef DBUG_ASSERT_EXISTS
6371

sql/item_create.cc

Lines changed: 39 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2590,6 +2590,41 @@ class Create_func_to_seconds : public Create_func_arg1
25902590
};
25912591

25922592

2593+
class Create_func_trunc : public Create_native_func
2594+
{
2595+
public:
2596+
Item *create_native(THD *thd, const LEX_CSTRING *name,
2597+
List<Item> *item_list) override
2598+
{
2599+
Item *a[2];
2600+
uint arg_count= item_list == nullptr ? 0 : item_list->elements;
2601+
2602+
for (uint i=0; i < MY_MIN(array_elements(a), arg_count); i++)
2603+
a[i]= item_list->pop();
2604+
switch (arg_count)
2605+
{
2606+
case 1:
2607+
{
2608+
a[1]= new (thd->mem_root) Item_string_sys(thd, "DD", 2);
2609+
if (unlikely(a[1] == nullptr))
2610+
return nullptr;
2611+
}
2612+
/*fall through*/
2613+
case 2:
2614+
return new (thd->mem_root) Item_func_trunc(thd, a[0], a[1]);
2615+
}
2616+
my_error(ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT, MYF(0), name->str);
2617+
return NULL;
2618+
}
2619+
2620+
static Create_func_trunc s_singleton;
2621+
2622+
protected:
2623+
Create_func_trunc() = default;
2624+
~Create_func_trunc() override = default;
2625+
};
2626+
2627+
25932628
class Create_func_ucase : public Create_func_arg1
25942629
{
25952630
public:
@@ -5986,6 +6021,9 @@ Create_func_to_seconds::create_1_arg(THD *thd, Item *arg1)
59866021
}
59876022

59886023

6024+
Create_func_trunc Create_func_trunc::s_singleton;
6025+
6026+
59896027
Create_func_ucase Create_func_ucase::s_singleton;
59906028

59916029
Item*
@@ -6555,6 +6593,7 @@ const Native_func_registry func_array[] =
65556593
{ { STRING_WITH_LEN("TO_CHAR") }, BUILDER(Create_func_to_char)},
65566594
{ { STRING_WITH_LEN("TO_DAYS") }, BUILDER(Create_func_to_days)},
65576595
{ { STRING_WITH_LEN("TO_SECONDS") }, BUILDER(Create_func_to_seconds)},
6596+
{ { STRING_WITH_LEN("TRUNC") }, BUILDER(Create_func_trunc)},
65586597
{ { STRING_WITH_LEN("UCASE") }, BUILDER(Create_func_ucase)},
65596598
{ { STRING_WITH_LEN("UNCOMPRESS") }, BUILDER(Create_func_uncompress)},
65606599
{ { STRING_WITH_LEN("UNCOMPRESSED_LENGTH") }, BUILDER(Create_func_uncompressed_length)},

0 commit comments

Comments
 (0)