Skip to content

Commit 2fcc2b4

Browse files
committed
MDEV-20023 Implement Oracle TRUNC() function
It returns the DATETIME data type (which is the closest to Oracle's DATE). 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, "DD") This patch incorporates a fix for: MDEV-37414 SIGSEGV in Binary_string::c_ptr | Item_func_trunc::get_date Fixing the problem that the code did not take into account that args[1] can return SQL NULL.
1 parent 038a05a commit 2fcc2b4

File tree

12 files changed

+628
-15
lines changed

12 files changed

+628
-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: 225 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,225 @@
1+
# Test for function trunc()
2+
SET NAMES utf8mb4;
3+
#
4+
# Simple test
5+
#
6+
select trunc('2025-07-27 12:01:02.123');
7+
trunc('2025-07-27 12:01:02.123')
8+
2025-07-27 00:00:00.000
9+
select trunc('2025-07-27 12:01:02.123','YY');
10+
trunc('2025-07-27 12:01:02.123','YY')
11+
2025-01-01 00:00:00.000
12+
select trunc('2025-07-27 12:01:02.123','MM');
13+
trunc('2025-07-27 12:01:02.123','MM')
14+
2025-07-01 00:00:00.000
15+
select trunc('2025-07-27 12:01:02.123','DD');
16+
trunc('2025-07-27 12:01:02.123','DD')
17+
2025-07-27 00:00:00.000
18+
select trunc('hello');
19+
trunc('hello')
20+
NULL
21+
Warnings:
22+
Warning 1292 Incorrect datetime value: 'hello'
23+
select trunc(1);
24+
trunc(1)
25+
NULL
26+
Warnings:
27+
Warning 1292 Incorrect datetime value: '1'
28+
#
29+
# The returned data type is DATETIME (the closest to Oracle's DATE)
30+
#
31+
CREATE TABLE t1 AS SELECT
32+
trunc('2025-07-27 12:01:02','YYYY') AS c0,
33+
trunc('2025-07-27 12:01:02.1','YYYY') AS c1,
34+
trunc('2025-07-27 12:01:02.12','YYYY') AS c2,
35+
trunc('2025-07-27 12:01:02.123','YYYY') AS c3,
36+
trunc('2025-07-27 12:01:02.1234','YYYY') AS c4,
37+
trunc('2025-07-27 12:01:02.12345','YYYY') AS c5,
38+
trunc('2025-07-27 12:01:02.123456','YYYY') AS c6,
39+
trunc('2025-07-27 12:01:02.1234567','YYYY') AS c7;
40+
Warnings:
41+
Note 1292 Truncated incorrect datetime value: '2025-07-27 12:01:02.1234567'
42+
SHOW CREATE TABLE t1;
43+
Table Create Table
44+
t1 CREATE TABLE `t1` (
45+
`c0` datetime DEFAULT NULL,
46+
`c1` datetime(1) DEFAULT NULL,
47+
`c2` datetime(2) DEFAULT NULL,
48+
`c3` datetime(3) DEFAULT NULL,
49+
`c4` datetime(4) DEFAULT NULL,
50+
`c5` datetime(5) DEFAULT NULL,
51+
`c6` datetime(6) DEFAULT NULL,
52+
`c7` datetime(6) DEFAULT NULL
53+
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_uca1400_ai_ci
54+
DROP TABLE t1;
55+
# Ensure that trunc table name and column can still be used
56+
create table trunc (trunc int);
57+
insert into trunc (trunc) values (1);
58+
select trunc from trunc;
59+
trunc
60+
1
61+
drop table trunc;
62+
#
63+
# Test all format variations
64+
#
65+
CREATE TABLE t1(c2 datetime, c3 date, c4 timestamp);
66+
INSERT INTO t1 VALUES ('2021-11-12 00:23:12', '2021-11-12', '2021-11-12 00:23:12');
67+
INSERT INTO t1 VALUES ('0000-09-02 00:00:00', '0000-09-02', '1980-09-02 00:00:00');
68+
INSERT INTO t1 VALUES ('9999-09-02', '9999-09-02', '1980-09-02');
69+
create table t2 (format varchar(5)) engine=aria;
70+
insert into t2 values ('DD'),('DDD'),('J'),('MM'),('MON'),('MONTH'),('RM'),('SYEAR'),('SYYYY'),('Y'),('YEAR'),('YY'),('YYY'),('YYYY'), ('ZZZ');
71+
SELECT format,trunc(c2,format),trunc(c3,format),trunc(c4,format) from t2 straight_join t1;
72+
format trunc(c2,format) trunc(c3,format) trunc(c4,format)
73+
DD 2021-11-12 00:00:00 2021-11-12 00:00:00 2021-11-12 00:00:00
74+
DDD 2021-11-12 00:00:00 2021-11-12 00:00:00 2021-11-12 00:00:00
75+
J 2021-11-12 00:00:00 2021-11-12 00:00:00 2021-11-12 00:00:00
76+
MM 2021-11-01 00:00:00 2021-11-01 00:00:00 2021-11-01 00:00:00
77+
MON 2021-11-01 00:00:00 2021-11-01 00:00:00 2021-11-01 00:00:00
78+
MONTH 2021-11-01 00:00:00 2021-11-01 00:00:00 2021-11-01 00:00:00
79+
RM 2021-11-01 00:00:00 2021-11-01 00:00:00 2021-11-01 00:00:00
80+
SYEAR 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
81+
SYYYY 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
82+
Y 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
83+
YEAR 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
84+
YY 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
85+
YYY 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
86+
YYYY 2021-01-01 00:00:00 2021-01-01 00:00:00 2021-01-01 00:00:00
87+
ZZZ NULL NULL NULL
88+
DD 0000-09-02 00:00:00 0000-09-02 00:00:00 1980-09-02 00:00:00
89+
DDD 0000-09-02 00:00:00 0000-09-02 00:00:00 1980-09-02 00:00:00
90+
J 0000-09-02 00:00:00 0000-09-02 00:00:00 1980-09-02 00:00:00
91+
MM 0000-09-01 00:00:00 0000-09-01 00:00:00 1980-09-01 00:00:00
92+
MON 0000-09-01 00:00:00 0000-09-01 00:00:00 1980-09-01 00:00:00
93+
MONTH 0000-09-01 00:00:00 0000-09-01 00:00:00 1980-09-01 00:00:00
94+
RM 0000-09-01 00:00:00 0000-09-01 00:00:00 1980-09-01 00:00:00
95+
SYEAR 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
96+
SYYYY 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
97+
Y 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
98+
YEAR 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
99+
YY 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
100+
YYY 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
101+
YYYY 0000-01-01 00:00:00 0000-01-01 00:00:00 1980-01-01 00:00:00
102+
ZZZ NULL NULL NULL
103+
DD 9999-09-02 00:00:00 9999-09-02 00:00:00 1980-09-02 00:00:00
104+
DDD 9999-09-02 00:00:00 9999-09-02 00:00:00 1980-09-02 00:00:00
105+
J 9999-09-02 00:00:00 9999-09-02 00:00:00 1980-09-02 00:00:00
106+
MM 9999-09-01 00:00:00 9999-09-01 00:00:00 1980-09-01 00:00:00
107+
MON 9999-09-01 00:00:00 9999-09-01 00:00:00 1980-09-01 00:00:00
108+
MONTH 9999-09-01 00:00:00 9999-09-01 00:00:00 1980-09-01 00:00:00
109+
RM 9999-09-01 00:00:00 9999-09-01 00:00:00 1980-09-01 00:00:00
110+
SYEAR 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
111+
SYYYY 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
112+
Y 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
113+
YEAR 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
114+
YY 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
115+
YYY 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
116+
YYYY 9999-01-01 00:00:00 9999-01-01 00:00:00 1980-01-01 00:00:00
117+
ZZZ NULL NULL NULL
118+
Warnings:
119+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
120+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
121+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
122+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
123+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
124+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
125+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
126+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
127+
Warning 1292 Incorrect TRUNC value: 'ZZZ'
128+
#
129+
# Test wrong usage
130+
#
131+
select trunc('2021-11-12 00:23:12','');
132+
trunc('2021-11-12 00:23:12','')
133+
NULL
134+
Warnings:
135+
Warning 1292 Incorrect TRUNC value: ''
136+
select trunc('2021-11-12 00:23:12','ZZZZ');
137+
trunc('2021-11-12 00:23:12','ZZZZ')
138+
NULL
139+
Warnings:
140+
Warning 1292 Incorrect TRUNC value: 'ZZZZ'
141+
select trunc('','DD');
142+
trunc('','DD')
143+
NULL
144+
Warnings:
145+
Warning 1292 Incorrect datetime value: ''
146+
select trunc();
147+
ERROR 42000: Incorrect parameter count in the call to native function 'trunc'
148+
select trunc(1);
149+
trunc(1)
150+
NULL
151+
Warnings:
152+
Warning 1292 Incorrect datetime value: '1'
153+
select trunc(1,2,3);
154+
ERROR 42000: Incorrect parameter count in the call to native function 'trunc'
155+
drop table t1,t2;
156+
select trunc('2021-11-12 00:23:12', POINT(1,1));
157+
ERROR HY000: Illegal parameter data type point for operation 'trunc'
158+
select trunc('2021-11-12 00:23:12', ROW(1,1));
159+
ERROR HY000: Illegal parameter data type row for operation 'trunc'
160+
select trunc(POINT(1,1), 'YYYY');
161+
ERROR HY000: Illegal parameter data type point for operation 'trunc'
162+
select trunc(ROW(1,1), 'YYYY');
163+
ERROR HY000: Illegal parameter data type row for operation 'trunc'
164+
select trunc(POINT(1,1));
165+
ERROR HY000: Illegal parameter data type point for operation 'trunc'
166+
select trunc(ROW(1,1));
167+
ERROR HY000: Illegal parameter data type row for operation 'trunc'
168+
#
169+
# Testing non-ASCII input in the format
170+
#
171+
SELECT trunc('2021-11-12 00:23:12','ŸŸŸŸ');
172+
trunc('2021-11-12 00:23:12','ŸŸŸŸ')
173+
NULL
174+
Warnings:
175+
Warning 1292 Incorrect TRUNC value: 'ŸŸŸŸ'
176+
#
177+
# Fractional digits outside of the supported limit of 6 digits
178+
# are always truncated even if TIME_ROUND_FRACTIONAL is set.
179+
#
180+
SET sql_mode=TIME_ROUND_FRACTIONAL;
181+
SELECT trunc('2001-12-31 23:59:59.9999999','YYYY') AS c1;
182+
c1
183+
2001-01-01 00:00:00.000000
184+
Warnings:
185+
Note 1292 Truncated incorrect datetime value: '2001-12-31 23:59:59.9999999'
186+
SELECT trunc('2001-12-31 23:59:59.9999999','MM') AS c1;
187+
c1
188+
2001-12-01 00:00:00.000000
189+
Warnings:
190+
Note 1292 Truncated incorrect datetime value: '2001-12-31 23:59:59.9999999'
191+
SELECT trunc('2001-12-31 23:59:59.9999999','DD') AS c1;
192+
c1
193+
2001-12-31 00:00:00.000000
194+
Warnings:
195+
Note 1292 Truncated incorrect datetime value: '2001-12-31 23:59:59.9999999'
196+
SET sql_mode=DEFAULT;
197+
#
198+
# TIME argument is converted to DATE using CURRENT_DATE
199+
#
200+
SET timestamp=unix_timestamp('2001-12-31 10:00:00');
201+
SELECT trunc(time'24:00:00','YYYY');
202+
trunc(time'24:00:00','YYYY')
203+
2002-01-01 00:00:00
204+
SELECT trunc(time'24:00:00','MM');
205+
trunc(time'24:00:00','MM')
206+
2002-01-01 00:00:00
207+
SELECT trunc(time'24:00:00','DD');
208+
trunc(time'24:00:00','DD')
209+
2002-01-01 00:00:00
210+
SET timestamp=DEFAULT;
211+
#
212+
# MDEV-37414 SIGSEGV in Binary_string::c_ptr | Item_func_trunc::get_date
213+
#
214+
SELECT trunc(time'24:00:00',NULL);
215+
trunc(time'24:00:00',NULL)
216+
NULL
217+
Warnings:
218+
Warning 1292 Incorrect TRUNC value: '<NULL>'
219+
SET SQL_MODE=EMPTY_STRING_IS_NULL;
220+
SELECT trunc(time'24:00:00','');
221+
trunc(time'24:00:00','')
222+
NULL
223+
Warnings:
224+
Warning 1292 Incorrect TRUNC value: '<NULL>'
225+
SET SQL_MODE=DEFAULT;
Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
1+
#
2+
# MDEV-20023 Implement Oracle TRUNC() function
3+
#
4+
SET NAMES utf8mb4, @@character_set_connection=ucs2;
5+
CREATE TABLE t1 (dt DATETIME);
6+
INSERT INTO t1 VALUES ('2001-02-03 10:20:30');
7+
SELECT trunc(dt, 'YYYY') FROM t1;
8+
trunc(dt, 'YYYY')
9+
2001-01-01 00:00:00
10+
SELECT trunc(dt, 'MM') FROM t1;
11+
trunc(dt, 'MM')
12+
2001-02-01 00:00:00
13+
SELECT trunc(dt, 'DD') FROM t1;
14+
trunc(dt, 'DD')
15+
2001-02-03 00:00:00
16+
CREATE TABLE t2 (fmt VARCHAR(32) CHARACTER SET ucs2);
17+
INSERT INTO t2 VALUES ('YYYY'),('MM'),('DD');
18+
SELECT trunc(dt, fmt) FROM t1, t2;
19+
trunc(dt, fmt)
20+
2001-01-01 00:00:00
21+
2001-02-01 00:00:00
22+
2001-02-03 00:00:00
23+
DROP TABLE t2;
24+
DROP TABLE t1;
25+
#
26+
# Testing non-ASCII input in the format
27+
#
28+
SELECT trunc('2021-11-12 00:23:12','ŸŸŸŸ');
29+
trunc('2021-11-12 00:23:12','ŸŸŸŸ')
30+
NULL
31+
Warnings:
32+
Warning 1292 Incorrect TRUNC value: '????'
Lines changed: 121 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,121 @@
1+
--echo # Test for function trunc()
2+
3+
SET NAMES utf8mb4;
4+
5+
--echo #
6+
--echo # Simple test
7+
--echo #
8+
9+
select trunc('2025-07-27 12:01:02.123');
10+
select trunc('2025-07-27 12:01:02.123','YY');
11+
select trunc('2025-07-27 12:01:02.123','MM');
12+
select trunc('2025-07-27 12:01:02.123','DD');
13+
14+
select trunc('hello');
15+
select trunc(1);
16+
17+
--echo #
18+
--echo # The returned data type is DATETIME (the closest to Oracle's DATE)
19+
--echo #
20+
21+
CREATE TABLE t1 AS SELECT
22+
trunc('2025-07-27 12:01:02','YYYY') AS c0,
23+
trunc('2025-07-27 12:01:02.1','YYYY') AS c1,
24+
trunc('2025-07-27 12:01:02.12','YYYY') AS c2,
25+
trunc('2025-07-27 12:01:02.123','YYYY') AS c3,
26+
trunc('2025-07-27 12:01:02.1234','YYYY') AS c4,
27+
trunc('2025-07-27 12:01:02.12345','YYYY') AS c5,
28+
trunc('2025-07-27 12:01:02.123456','YYYY') AS c6,
29+
trunc('2025-07-27 12:01:02.1234567','YYYY') AS c7;
30+
SHOW CREATE TABLE t1;
31+
DROP TABLE t1;
32+
33+
34+
--echo # Ensure that trunc table name and column can still be used
35+
36+
create table trunc (trunc int);
37+
insert into trunc (trunc) values (1);
38+
select trunc from trunc;
39+
drop table trunc;
40+
41+
--echo #
42+
--echo # Test all format variations
43+
--echo #
44+
45+
CREATE TABLE t1(c2 datetime, c3 date, c4 timestamp);
46+
INSERT INTO t1 VALUES ('2021-11-12 00:23:12', '2021-11-12', '2021-11-12 00:23:12');
47+
INSERT INTO t1 VALUES ('0000-09-02 00:00:00', '0000-09-02', '1980-09-02 00:00:00');
48+
INSERT INTO t1 VALUES ('9999-09-02', '9999-09-02', '1980-09-02');
49+
50+
create table t2 (format varchar(5)) engine=aria;
51+
insert into t2 values ('DD'),('DDD'),('J'),('MM'),('MON'),('MONTH'),('RM'),('SYEAR'),('SYYYY'),('Y'),('YEAR'),('YY'),('YYY'),('YYYY'), ('ZZZ');
52+
53+
SELECT format,trunc(c2,format),trunc(c3,format),trunc(c4,format) from t2 straight_join t1;
54+
55+
--echo #
56+
--echo # Test wrong usage
57+
--echo #
58+
59+
select trunc('2021-11-12 00:23:12','');
60+
select trunc('2021-11-12 00:23:12','ZZZZ');
61+
select trunc('','DD');
62+
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
63+
select trunc();
64+
select trunc(1);
65+
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
66+
select trunc(1,2,3);
67+
68+
drop table t1,t2;
69+
70+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
71+
select trunc('2021-11-12 00:23:12', POINT(1,1));
72+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
73+
select trunc('2021-11-12 00:23:12', ROW(1,1));
74+
75+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
76+
select trunc(POINT(1,1), 'YYYY');
77+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
78+
select trunc(ROW(1,1), 'YYYY');
79+
80+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
81+
select trunc(POINT(1,1));
82+
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
83+
select trunc(ROW(1,1));
84+
85+
--echo #
86+
--echo # Testing non-ASCII input in the format
87+
--echo #
88+
89+
SELECT trunc('2021-11-12 00:23:12','ŸŸŸŸ');
90+
91+
92+
--echo #
93+
--echo # Fractional digits outside of the supported limit of 6 digits
94+
--echo # are always truncated even if TIME_ROUND_FRACTIONAL is set.
95+
--echo #
96+
97+
SET sql_mode=TIME_ROUND_FRACTIONAL;
98+
SELECT trunc('2001-12-31 23:59:59.9999999','YYYY') AS c1;
99+
SELECT trunc('2001-12-31 23:59:59.9999999','MM') AS c1;
100+
SELECT trunc('2001-12-31 23:59:59.9999999','DD') AS c1;
101+
SET sql_mode=DEFAULT;
102+
103+
--echo #
104+
--echo # TIME argument is converted to DATE using CURRENT_DATE
105+
--echo #
106+
107+
SET timestamp=unix_timestamp('2001-12-31 10:00:00');
108+
SELECT trunc(time'24:00:00','YYYY');
109+
SELECT trunc(time'24:00:00','MM');
110+
SELECT trunc(time'24:00:00','DD');
111+
SET timestamp=DEFAULT;
112+
113+
114+
--echo #
115+
--echo # MDEV-37414 SIGSEGV in Binary_string::c_ptr | Item_func_trunc::get_date
116+
--echo #
117+
118+
SELECT trunc(time'24:00:00',NULL);
119+
SET SQL_MODE=EMPTY_STRING_IS_NULL;
120+
SELECT trunc(time'24:00:00','');
121+
SET SQL_MODE=DEFAULT;

0 commit comments

Comments
 (0)