Skip to content

Commit cd483cf

Browse files
committed
MDEV-37319 Oracle Compatibility - MONTHS_BETWEEN functions
If one compiles with EXTENDED_MONTHS_BETWEEN MariaDB would take hours, minutes, seconds and fractional seconds into account when comparing dates when computing the fractional months. For example MONTHS_BETWEEN("1995-02-15 12:00:00", "1995-01-17 12:00:01") would return "one day less" than if time part would not have been given.
1 parent 2fcc2b4 commit cd483cf

File tree

5 files changed

+285
-0
lines changed

5 files changed

+285
-0
lines changed
Lines changed: 79 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,79 @@
1+
# Test for function trunc()
2+
#
3+
# Test 'same day, different months'. Result is an integer
4+
#
5+
select months_between("1995-02-15", "1995-01-15");
6+
months_between("1995-02-15", "1995-01-15")
7+
1
8+
select months_between("1995-02-15", "1995-01-15 11:59:59");
9+
months_between("1995-02-15", "1995-01-15 11:59:59")
10+
1
11+
select months_between("1995-02-15 02:01:01", "1995-01-15 01:00:01");
12+
months_between("1995-02-15 02:01:01", "1995-01-15 01:00:01")
13+
1
14+
select months_between("2000-02-29", "1999-02-28");
15+
months_between("2000-02-29", "1999-02-28")
16+
12
17+
select months_between("2001-04-30", "1999-05-31");
18+
months_between("2001-04-30", "1999-05-31")
19+
23
20+
# Test different days. Result has decimals
21+
select months_between("1995-02-02", "1995-01-01");
22+
months_between("1995-02-02", "1995-01-01")
23+
1.032258064516129
24+
select months_between("1995-01-01", "1995-02-02");
25+
months_between("1995-01-01", "1995-02-02")
26+
-1.032258064516129
27+
# Test one day difference
28+
select months_between("1995-02-15", "1995-01-15");
29+
months_between("1995-02-15", "1995-01-15")
30+
1
31+
select months_between("1995-02-15", "1995-01-14");
32+
months_between("1995-02-15", "1995-01-14")
33+
1.032258064516129
34+
select months_between("1995-02-15", "1995-01-16");
35+
months_between("1995-02-15", "1995-01-16")
36+
0.967741935483871
37+
# Test effect on different times different time
38+
select months_between("1995-02-15 12:00:00", "1995-01-16 12:00:00");
39+
months_between("1995-02-15 12:00:00", "1995-01-16 12:00:00")
40+
0.967741935483871
41+
select months_between("1995-02-15 12:00:00", "1995-01-16 11:59:59");
42+
months_between("1995-02-15 12:00:00", "1995-01-16 11:59:59")
43+
0.9677423088410991
44+
select months_between("1995-02-15 12:00:00", "1995-01-16 12:00:01");
45+
months_between("1995-02-15 12:00:00", "1995-01-16 12:00:01")
46+
0.9677415621266429
47+
#
48+
# Test difference in hours
49+
#
50+
SET sql_mode=ORACLE;
51+
CREATE TABLE t1 (a DATE, b DATE);
52+
show create table t1;
53+
Table Create Table
54+
t1 CREATE TABLE "t1" (
55+
"a" datetime DEFAULT NULL,
56+
"b" datetime DEFAULT NULL
57+
)
58+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00',TIMESTAMP'2001-01-01 23:00:00');
59+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00', TIMESTAMP'2001-01-01 00:00:00');
60+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:00:00', TIMESTAMP'2001-01-01 00:00:00');
61+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:30:00', TIMESTAMP'2001-01-01 00:00:00');
62+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00',TIMESTAMP'2001-01-03 23:00:00');
63+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00', TIMESTAMP'2001-01-03 00:00:00');
64+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:00:00', TIMESTAMP'2001-01-03 00:00:00');
65+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:30:00', TIMESTAMP'2001-01-03 00:00:00');
66+
INSERT INTO t1 VALUES(TIMESTAMP'1900-01-01 00:00:00', TIMESTAMP'9999-12-31 23:59:59');
67+
SELECT a,b, MONTHS_BETWEEN(a,b) AS c FROM t1;
68+
a b c
69+
2001-01-02 00:00:00 2001-01-01 23:00:00 0.0013440860215053752
70+
2001-01-02 00:00:00 2001-01-01 00:00:00 0.03225806451612903
71+
2001-01-02 23:00:00 2001-01-01 00:00:00 0.06317204301075269
72+
2001-01-02 23:30:00 2001-01-01 00:00:00 0.06384408602150538
73+
2001-01-02 00:00:00 2001-01-03 23:00:00 -0.06317204301075269
74+
2001-01-02 00:00:00 2001-01-03 00:00:00 -0.03225806451612903
75+
2001-01-02 23:00:00 2001-01-03 00:00:00 -0.0013440860215053752
76+
2001-01-02 23:30:00 2001-01-03 00:00:00 -0.0006720430107526894
77+
1900-01-01 00:00:00 9999-12-31 23:59:59 -97199.99999962664
78+
set sql_mode=default;
79+
drop table t1;
Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
--echo # Test for function trunc()
2+
3+
--echo #
4+
--echo # Test 'same day, different months'. Result is an integer
5+
--echo #
6+
7+
select months_between("1995-02-15", "1995-01-15");
8+
select months_between("1995-02-15", "1995-01-15 11:59:59");
9+
select months_between("1995-02-15 02:01:01", "1995-01-15 01:00:01");
10+
select months_between("2000-02-29", "1999-02-28");
11+
select months_between("2001-04-30", "1999-05-31");
12+
13+
--echo # Test different days. Result has decimals
14+
15+
select months_between("1995-02-02", "1995-01-01");
16+
select months_between("1995-01-01", "1995-02-02");
17+
18+
--echo # Test one day difference
19+
select months_between("1995-02-15", "1995-01-15");
20+
select months_between("1995-02-15", "1995-01-14");
21+
select months_between("1995-02-15", "1995-01-16");
22+
23+
--echo # Test effect on different times different time
24+
25+
select months_between("1995-02-15 12:00:00", "1995-01-16 12:00:00");
26+
select months_between("1995-02-15 12:00:00", "1995-01-16 11:59:59");
27+
select months_between("1995-02-15 12:00:00", "1995-01-16 12:00:01");
28+
29+
--echo #
30+
--echo # Test difference in hours
31+
--echo #
32+
33+
SET sql_mode=ORACLE;
34+
CREATE TABLE t1 (a DATE, b DATE);
35+
show create table t1;
36+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00',TIMESTAMP'2001-01-01 23:00:00');
37+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00', TIMESTAMP'2001-01-01 00:00:00');
38+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:00:00', TIMESTAMP'2001-01-01 00:00:00');
39+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:30:00', TIMESTAMP'2001-01-01 00:00:00');
40+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00',TIMESTAMP'2001-01-03 23:00:00');
41+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 00:00:00', TIMESTAMP'2001-01-03 00:00:00');
42+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:00:00', TIMESTAMP'2001-01-03 00:00:00');
43+
INSERT INTO t1 VALUES(TIMESTAMP'2001-01-02 23:30:00', TIMESTAMP'2001-01-03 00:00:00');
44+
INSERT INTO t1 VALUES(TIMESTAMP'1900-01-01 00:00:00', TIMESTAMP'9999-12-31 23:59:59');
45+
SELECT a,b, MONTHS_BETWEEN(a,b) AS c FROM t1;
46+
set sql_mode=default;
47+
drop table t1;

sql/item_create.cc

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1916,6 +1916,18 @@ class Create_func_monthname : public Create_func_arg1
19161916
~Create_func_monthname() override = default;
19171917
};
19181918

1919+
class Create_func_months_between : public Create_func_arg2
1920+
{
1921+
public:
1922+
Item *create_2_arg(THD *thd, Item *arg1, Item *arg2) override;
1923+
1924+
static Create_func_months_between s_singleton;
1925+
1926+
protected:
1927+
Create_func_months_between() = default;
1928+
~Create_func_months_between() override = default;
1929+
};
1930+
19191931

19201932
class Create_func_name_const : public Create_func_arg2
19211933
{
@@ -5375,6 +5387,15 @@ Create_func_monthname::create_1_arg(THD *thd, Item *arg1)
53755387
}
53765388

53775389

5390+
Create_func_months_between Create_func_months_between::s_singleton;
5391+
5392+
Item*
5393+
Create_func_months_between::create_2_arg(THD *thd, Item *arg1, Item *arg2)
5394+
{
5395+
return new (thd->mem_root) Item_func_months_between(thd, arg1, arg2);
5396+
}
5397+
5398+
53785399
Create_func_name_const Create_func_name_const::s_singleton;
53795400

53805401
Item*
@@ -6531,6 +6552,7 @@ const Native_func_registry func_array[] =
65316552
{ { STRING_WITH_LEN("MICROSECOND") }, BUILDER(Create_func_microsecond)},
65326553
{ { STRING_WITH_LEN("MOD") }, BUILDER(Create_func_mod)},
65336554
{ { STRING_WITH_LEN("MONTHNAME") }, BUILDER(Create_func_monthname)},
6555+
{ { STRING_WITH_LEN("MONTHS_BETWEEN") }, BUILDER(Create_func_months_between)},
65346556
{ { STRING_WITH_LEN("NAME_CONST") }, BUILDER(Create_func_name_const)},
65356557
{ {STRING_WITH_LEN("NATURAL_SORT_KEY")}, BUILDER(Create_func_natural_sort_key)},
65366558
{ { STRING_WITH_LEN("NVL") }, BUILDER(Create_func_ifnull)},

sql/item_timefunc.cc

Lines changed: 119 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4169,3 +4169,122 @@ bool Item_func_trunc::get_date(THD *thd, MYSQL_TIME *ltime,
41694169
null_value= 1;
41704170
return true;
41714171
}
4172+
4173+
4174+
/*
4175+
Help functions for months_between()
4176+
Note that by compiling with EXTENDED_MONTHS_BETWEEN MariaDB would
4177+
take into account alse the time part when comparing dates.
4178+
*/
4179+
4180+
static ulonglong months_between_rank(const MYSQL_TIME *t)
4181+
{
4182+
ulonglong days= (((t->year * 366LL) + t->month) * 31 + t->day);
4183+
#ifndef EXTENDED_MONTHS_BETWEEN
4184+
return days;
4185+
#else
4186+
ulonglong rank= (((((days*24 + t->hour) * 60) + t->minute) * 60 +
4187+
t->second)*1000000LL + t->second_part);
4188+
return rank;
4189+
#endif /* EXTENDED_MONTHS_BETWEEN */
4190+
}
4191+
4192+
4193+
/*
4194+
Get the fractional day based on hour, minute, second and
4195+
fractional second. The return value is in milliseconds.
4196+
*/
4197+
4198+
static double fractional_day(const MYSQL_TIME *t)
4199+
{
4200+
/* Normalize all components to the fractional part of the day */
4201+
ulonglong milliseconds= (t->hour * 3600LL + t->minute * 60LL +
4202+
t->second)*1000;
4203+
4204+
#ifdef EXTENDED_MONTHS_BETWEEN
4205+
milliseconds+= t->second_part / 1000;
4206+
#endif
4207+
4208+
/*
4209+
Normalize by 86400000
4210+
(which is 24 hours * 60 minutes * 60 seconds * 1000 milliseconds)
4211+
*/
4212+
return milliseconds / 86400000.0; // fractional day
4213+
}
4214+
4215+
4216+
/* Check if it's the last day of the month */
4217+
static inline int is_last_day(const MYSQL_TIME *ltime)
4218+
{
4219+
uint last_day= calc_days_in_month(ltime->year, ltime->month);
4220+
return ltime->day == last_day;
4221+
}
4222+
4223+
/*
4224+
Calculate months_between() according to how Oracle does it.
4225+
4226+
"If date1 is earlier than date2, then the result is negative. If
4227+
date1 and date2 are either the same days of the month or both last
4228+
days of months, then the result is always an integer. If not, then
4229+
a fractional portion is added based on a 31-day month.
4230+
4231+
One difference between the MariaDB and Oracle implementation is that
4232+
MariaDB takes hours, minutes, seconds and fractional seconds into
4233+
account when comparing dates when computing the fractional months.
4234+
*/
4235+
4236+
double Item_func_months_between::val_real()
4237+
{
4238+
double frac;
4239+
int invert = 1, months;
4240+
ulonglong dt1, dt2;
4241+
MYSQL_TIME ltime1, ltime2, *d1, *d2;
4242+
THD *thd= current_thd;
4243+
Datetime::Options opt(TIME_NO_ZEROS, thd);
4244+
4245+
if (Datetime(thd, args[0], opt).copy_to_mysql_time(&ltime1) ||
4246+
Datetime(thd, args[1], opt).copy_to_mysql_time(&ltime2))
4247+
{
4248+
null_value= 1;
4249+
return 0.0;
4250+
}
4251+
null_value= 0;
4252+
4253+
/* Get earlier time in d1 */
4254+
d1= &ltime1;
4255+
d2= &ltime2;
4256+
4257+
dt1= months_between_rank(d1);
4258+
dt2= months_between_rank(d2);
4259+
4260+
if (dt1 < dt2)
4261+
{
4262+
invert= -1;
4263+
swap_variables(MYSQL_TIME *, d1, d2);
4264+
}
4265+
4266+
/* Calculate months */
4267+
months= (d1->year - d2->year) * 12 + (d1->month - d2->month);
4268+
4269+
/*
4270+
If days are the same or day is last day of the month they are
4271+
regarded as equal
4272+
*/
4273+
if (d1->day == d2->day || (is_last_day(d1) && is_last_day(d2)))
4274+
return months * invert;
4275+
4276+
double frac_d1, frac_d2;
4277+
frac_d1= fractional_day(d1);
4278+
frac_d2= fractional_day(d2);
4279+
4280+
/* Compute fractional month using 31-day assumption */
4281+
if (d1->day > d2->day)
4282+
frac= (d1->day + frac_d1 - d2->day - frac_d2) / 31.0;
4283+
else
4284+
{
4285+
months--;
4286+
frac= (31 - d2->day - frac_d2 + d1->day + frac_d1) / 31.0;
4287+
}
4288+
4289+
return invert * (months + frac);
4290+
}

sql/item_timefunc.h

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2177,4 +2177,22 @@ class Item_func_trunc :public Item_datetimefunc
21772177
{ return get_item_copy<Item_func_trunc>(thd, this); }
21782178
};
21792179

2180+
2181+
class Item_func_months_between : public Item_real_func
2182+
{
2183+
bool check_arguments() const override
2184+
{ return check_argument_types_can_return_date(0, arg_count); }
2185+
public:
2186+
Item_func_months_between(THD *thd, Item *a, Item *b):
2187+
Item_real_func(thd, a, b) {}
2188+
double val_real() override;
2189+
LEX_CSTRING func_name_cstring() const override
2190+
{
2191+
static LEX_CSTRING name= {STRING_WITH_LEN("months_between") };
2192+
return name;
2193+
}
2194+
Item *do_get_copy(THD *thd) const override
2195+
{ return get_item_copy<Item_func_months_between>(thd, this); }
2196+
};
2197+
21802198
#endif /* ITEM_TIMEFUNC_INCLUDED */

0 commit comments

Comments
 (0)