Commit e84f7939 authored by unknown's avatar unknown

Fix calculation of TIMESTAMPDIFF() of months and years. (Bug #13534)


mysql-test/r/func_time.result:
  Add new results
mysql-test/t/func_time.test:
  Add new regression test
sql/item_timefunc.cc:
  Fix calculation of years and months in TIMESTAMPDIFF().
parent 979446f3
...@@ -760,3 +760,54 @@ call t_sysdate(); ...@@ -760,3 +760,54 @@ call t_sysdate();
@a != @b @a != @b
1 1
drop procedure t_sysdate; drop procedure t_sysdate;
select timestampdiff(month,'2004-09-11','2004-09-11');
timestampdiff(month,'2004-09-11','2004-09-11')
0
select timestampdiff(month,'2004-09-11','2005-09-11');
timestampdiff(month,'2004-09-11','2005-09-11')
12
select timestampdiff(month,'2004-09-11','2006-09-11');
timestampdiff(month,'2004-09-11','2006-09-11')
24
select timestampdiff(month,'2004-09-11','2007-09-11');
timestampdiff(month,'2004-09-11','2007-09-11')
36
select timestampdiff(month,'2005-09-11','2004-09-11');
timestampdiff(month,'2005-09-11','2004-09-11')
-12
select timestampdiff(month,'2005-09-11','2003-09-11');
timestampdiff(month,'2005-09-11','2003-09-11')
-24
select timestampdiff(month,'2004-02-28','2005-02-28');
timestampdiff(month,'2004-02-28','2005-02-28')
12
select timestampdiff(month,'2004-02-29','2005-02-28');
timestampdiff(month,'2004-02-29','2005-02-28')
11
select timestampdiff(month,'2004-02-28','2005-02-28');
timestampdiff(month,'2004-02-28','2005-02-28')
12
select timestampdiff(month,'2004-03-29','2005-03-28');
timestampdiff(month,'2004-03-29','2005-03-28')
11
select timestampdiff(month,'2003-02-28','2004-02-29');
timestampdiff(month,'2003-02-28','2004-02-29')
12
select timestampdiff(month,'2003-02-28','2005-02-28');
timestampdiff(month,'2003-02-28','2005-02-28')
24
select timestampdiff(month,'1999-09-11','2001-10-10');
timestampdiff(month,'1999-09-11','2001-10-10')
24
select timestampdiff(month,'1999-09-11','2001-9-11');
timestampdiff(month,'1999-09-11','2001-9-11')
24
select timestampdiff(year,'1999-09-11','2001-9-11');
timestampdiff(year,'1999-09-11','2001-9-11')
2
select timestampdiff(year,'2004-02-28','2005-02-28');
timestampdiff(year,'2004-02-28','2005-02-28')
1
select timestampdiff(year,'2004-02-29','2005-02-28');
timestampdiff(year,'2004-02-29','2005-02-28')
0
...@@ -404,4 +404,28 @@ delimiter ;// ...@@ -404,4 +404,28 @@ delimiter ;//
call t_sysdate(); call t_sysdate();
drop procedure t_sysdate; drop procedure t_sysdate;
#
# Bug #13534: timestampdiff() returned incorrect results across leap years
#
select timestampdiff(month,'2004-09-11','2004-09-11');
select timestampdiff(month,'2004-09-11','2005-09-11');
select timestampdiff(month,'2004-09-11','2006-09-11');
select timestampdiff(month,'2004-09-11','2007-09-11');
select timestampdiff(month,'2005-09-11','2004-09-11');
select timestampdiff(month,'2005-09-11','2003-09-11');
select timestampdiff(month,'2004-02-28','2005-02-28');
select timestampdiff(month,'2004-02-29','2005-02-28');
select timestampdiff(month,'2004-02-28','2005-02-28');
select timestampdiff(month,'2004-03-29','2005-03-28');
select timestampdiff(month,'2003-02-28','2004-02-29');
select timestampdiff(month,'2003-02-28','2005-02-28');
select timestampdiff(month,'1999-09-11','2001-10-10');
select timestampdiff(month,'1999-09-11','2001-9-11');
select timestampdiff(year,'1999-09-11','2001-9-11');
select timestampdiff(year,'2004-02-28','2005-02-28');
select timestampdiff(year,'2004-02-29','2005-02-28');
# End of 5.0 tests # End of 5.0 tests
...@@ -2723,16 +2723,16 @@ longlong Item_func_timestamp_diff::val_int() ...@@ -2723,16 +2723,16 @@ longlong Item_func_timestamp_diff::val_int()
int_type == INTERVAL_QUARTER || int_type == INTERVAL_QUARTER ||
int_type == INTERVAL_MONTH) int_type == INTERVAL_MONTH)
{ {
uint year; uint year_beg, year_end, month_beg, month_end, day_beg, day_end;
uint year_beg, year_end, month_beg, month_end; uint years= 0;
uint diff_days= (uint) (seconds/86400L);
uint diff_years= 0;
if (neg == -1) if (neg == -1)
{ {
year_beg= ltime2.year; year_beg= ltime2.year;
year_end= ltime1.year; year_end= ltime1.year;
month_beg= ltime2.month; month_beg= ltime2.month;
month_end= ltime1.month; month_end= ltime1.month;
day_beg= ltime2.day;
day_end= ltime1.day;
} }
else else
{ {
...@@ -2740,53 +2740,32 @@ longlong Item_func_timestamp_diff::val_int() ...@@ -2740,53 +2740,32 @@ longlong Item_func_timestamp_diff::val_int()
year_end= ltime2.year; year_end= ltime2.year;
month_beg= ltime1.month; month_beg= ltime1.month;
month_end= ltime2.month; month_end= ltime2.month;
} day_beg= ltime1.day;
/* calc years*/ day_end= ltime2.day;
for (year= year_beg;year < year_end; year++)
{
uint days=calc_days_in_year(year);
if (days > diff_days)
break;
diff_days-= days;
diff_years++;
} }
/* calc months; Current year is in the 'year' variable */ /* calc years */
month_beg--; /* Change months to be 0-11 for easier calculation */ years= year_end - year_beg;
month_end--; if (month_end < month_beg || (month_end == month_beg && day_end < day_beg))
years-= 1;
months= 12*diff_years; /* calc months */
while (month_beg != month_end) months= 12*years;
{ if (month_end < month_beg || (month_end == month_beg && day_end < day_beg))
uint m_days= (uint) days_in_month[month_beg]; months+= 12 - (month_beg - month_end);
if (month_beg == 1) else
{ months+= (month_end - month_beg);
/* This is only calculated once so there is no reason to cache it*/ if (day_end < day_beg)
uint leap= (uint) ((year & 3) == 0 && (year%100 || months-= 1;
(year%400 == 0 && year)));
m_days+= leap;
}
if (m_days > diff_days)
break;
diff_days-= m_days;
months++;
if (month_beg++ == 11) /* if we wrap to next year */
{
month_beg= 0;
year++;
}
}
if (neg == -1)
months= -months;
} }
switch (int_type) { switch (int_type) {
case INTERVAL_YEAR: case INTERVAL_YEAR:
return months/12; return months/12*neg;
case INTERVAL_QUARTER: case INTERVAL_QUARTER:
return months/3; return months/3*neg;
case INTERVAL_MONTH: case INTERVAL_MONTH:
return months; return months*neg;
case INTERVAL_WEEK: case INTERVAL_WEEK:
return seconds/86400L/7L*neg; return seconds/86400L/7L*neg;
case INTERVAL_DAY: case INTERVAL_DAY:
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment