This section describes the functions that can be used to manipulate temporal values. See Section 10.3, “Date and Time Types”, for a description of the range of values each date and time type has and the valid formats in which values may be specified.
Table 11.12. Date/Time Functions
Name | Description |
---|---|
ADDDATE() (v4.1.1) |
Add time values (intervals) to a date value |
ADDTIME() (v4.1.1) |
Add time |
CONVERT_TZ() (v4.1.3) |
Convert from one timezone to another |
CURDATE() |
Return the current date |
CURRENT_DATE() , CURRENT_DATE |
Synonyms for CURDATE() |
CURRENT_TIME() , CURRENT_TIME |
Synonyms for CURTIME() |
CURRENT_TIMESTAMP() , CURRENT_TIMESTAMP |
Synonyms for NOW() |
CURTIME() |
Return the current time |
DATE_ADD() |
Add time values (intervals) to a date value |
DATE_FORMAT() |
Format date as specified |
DATE_SUB() |
Subtract a time value (interval) from a date |
DATE() (v4.1.1) |
Extract the date part of a date or datetime expression |
DATEDIFF() (v4.1.1) |
Subtract two dates |
DAY() (v4.1.1) |
Synonym for DAYOFMONTH() |
DAYNAME() (v4.1.21) |
Return the name of the weekday |
DAYOFMONTH() |
Return the day of the month (0-31) |
DAYOFWEEK() |
Return the weekday index of the argument |
DAYOFYEAR() |
Return the day of the year (1-366) |
EXTRACT() |
Extract part of a date |
FROM_DAYS() |
Convert a day number to a date |
FROM_UNIXTIME() |
Format UNIX timestamp as a date |
GET_FORMAT() (v4.1.1) |
Return a date format string |
HOUR() |
Extract the hour |
LAST_DAY (v4.1.1) |
Return the last day of the month for the argument |
LOCALTIME() , LOCALTIME |
Synonym for NOW() |
LOCALTIMESTAMP , LOCALTIMESTAMP() (v4.0.6) |
Synonym for NOW() |
MAKEDATE() (v4.1.1) |
Create a date from the year and day of year |
MAKETIME (v4.1.1) |
MAKETIME() |
MICROSECOND() (v4.1.1) |
Return the microseconds from argument |
MINUTE() |
Return the minute from the argument |
MONTH() |
Return the month from the date passed |
MONTHNAME() (v4.1.21) |
Return the name of the month |
NOW() |
Return the current date and time |
PERIOD_ADD() |
Add a period to a year-month |
PERIOD_DIFF() |
Return the number of months between periods |
QUARTER() |
Return the quarter from a date argument |
SEC_TO_TIME() |
Converts seconds to 'HH:MM:SS' format |
SECOND() |
Return the second (0-59) |
STR_TO_DATE() (v4.1.1) |
Convert a string to a date |
SUBDATE() |
A synonym for DATE_SUB() when invoked with three arguments |
SUBTIME() (v4.1.1) |
Subtract times |
SYSDATE() |
Return the time at which the function executes |
TIME_FORMAT() |
Format as time |
TIME_TO_SEC() |
Return the argument converted to seconds |
TIME() (v4.1.1) |
Extract the time portion of the expression passed |
TIMEDIFF() (v4.1.1) |
Subtract time |
TIMESTAMP() (v4.1.1) |
With a single argument, this function returns the date or datetime expression; with two arguments, the sum of the arguments |
TIMESTAMPADD() (v5.0.0) |
Add an interval to a datetime expression |
TIMESTAMPDIFF() (v5.0.0) |
Subtract an interval from a datetime expression |
TO_DAYS() |
Return the date argument converted to days |
UNIX_TIMESTAMP() |
Return a UNIX timestamp |
UTC_DATE() (v4.1.1) |
Return the current UTC date |
UTC_TIME() (v4.1.1) |
Return the current UTC time |
UTC_TIMESTAMP() (v4.1.1) |
Return the current UTC date and time |
WEEK() |
Return the week number |
WEEKDAY() |
Return the weekday index |
WEEKOFYEAR() (v4.1.1) |
Return the calendar week of the date (0-53) |
YEAR() |
Return the year |
YEARWEEK() |
Return the year and week |
Here is an example that uses date functions. The following query
selects all rows with a date_col
value
from within the last 30 days:
mysql>SELECT
->something
FROMtbl_name
WHERE DATE_SUB(CURDATE(),INTERVAL 30 DAY) <=
date_col
;
The query also selects rows with dates that lie in the future.
Functions that expect date values usually accept datetime values and ignore the time part. Functions that expect time values usually accept datetime values and ignore the date part.
Functions that return the current date or time each are evaluated
only once per query at the start of query execution. This means
that multiple references to a function such as
NOW()
within a single query always
produce the same result. (For our purposes, a single query also
includes a call to a stored program (stored routine or trigger)
and all subprograms called by that program.) This principle also
applies to CURDATE()
,
CURTIME()
,
UTC_DATE()
,
UTC_TIME()
,
UTC_TIMESTAMP()
, and to any of
their synonyms.
The CURRENT_TIMESTAMP()
,
CURRENT_TIME()
,
CURRENT_DATE()
, and
FROM_UNIXTIME()
functions return
values in the connection's current time zone, which is available
as the value of the time_zone
system variable. In addition,
UNIX_TIMESTAMP()
assumes that its
argument is a datetime value in the current time zone. See
Section 9.6, “MySQL Server Time Zone Support”.
Some date functions can be used with “zero” dates or
incomplete dates such as '2001-11-00'
, whereas
others cannot. Functions that extract parts of dates typically
work with incomplete dates and thus can return 0 when you might
otherwise expect a nonzero value. For example:
mysql> SELECT DAYOFMONTH('2001-11-00'), MONTH('2005-00-00');
-> 0, 0
Other functions expect complete dates and return
NULL
for incomplete dates. These include
functions that perform date arithmetic or that map parts of dates
to names. For example:
mysql>SELECT DATE_ADD('2006-05-00',INTERVAL 1 DAY);
-> NULL mysql>SELECT DAYNAME('2006-05-00');
-> NULL
ADDDATE(
,
date
,INTERVAL
expr
unit
)ADDDATE(
expr
,days
)
When invoked with the INTERVAL
form of the
second argument, ADDDATE()
is a
synonym for DATE_ADD()
. The
related function SUBDATE()
is a
synonym for DATE_SUB()
. For
information on the INTERVAL
unit
argument, see the discussion
for DATE_ADD()
.
mysql>SELECT DATE_ADD('2008-01-02', INTERVAL 31 DAY);
-> '2008-02-02' mysql>SELECT ADDDATE('2008-01-02', INTERVAL 31 DAY);
-> '2008-02-02'
When invoked with the days
form of
the second argument, MySQL treats it as an integer number of
days to be added to expr
.
mysql> SELECT ADDDATE('2008-01-02', 31);
-> '2008-02-02'
ADDTIME()
adds
expr2
to
expr1
and returns the result.
expr1
is a time or datetime
expression, and expr2
is a time
expression.
mysql>SELECT ADDTIME('2007-12-31 23:59:59.999999', '1 1:1:1.000002');
-> '2008-01-02 01:01:01.000001' mysql>SELECT ADDTIME('01:00:00.999999', '02:00:00.999998');
-> '03:00:01.999997'
CONVERT_TZ()
converts a
datetime value dt
from the time
zone given by from_tz
to the time
zone given by to_tz
and returns the
resulting value. Time zones are specified as described in
Section 9.6, “MySQL Server Time Zone Support”. This function returns
NULL
if the arguments are invalid.
If the value falls out of the supported range of the
TIMESTAMP
type when converted
from from_tz
to UTC, no conversion
occurs. The TIMESTAMP
range is
described in Section 10.1.2, “Overview of Date and Time Types”.
mysql>SELECT CONVERT_TZ('2004-01-01 12:00:00','GMT','MET');
-> '2004-01-01 13:00:00' mysql>SELECT CONVERT_TZ('2004-01-01 12:00:00','+00:00','+10:00');
-> '2004-01-01 22:00:00'
To use named time zones such as 'MET'
or
'Europe/Moscow'
, the time zone tables
must be properly set up. See
Section 9.6, “MySQL Server Time Zone Support”, for instructions.
If you intend to use
CONVERT_TZ()
while other tables
are locked with LOCK TABLES
,
you must also lock the mysql.time_zone_name
table.
Returns the current date as a value in
'YYYY-MM-DD'
or YYYYMMDD
format, depending on whether the function is used in a string
or numeric context.
mysql>SELECT CURDATE();
-> '2008-06-13' mysql>SELECT CURDATE() + 0;
-> 20080613
CURRENT_DATE
and
CURRENT_DATE()
are synonyms for
CURDATE()
.
Returns the current time as a value in
'HH:MM:SS'
or
HHMMSS.uuuuuu
format, depending on whether
the function is used in a string or numeric context. The value
is expressed in the current time zone.
mysql>SELECT CURTIME();
-> '23:50:26' mysql>SELECT CURTIME() + 0;
-> 235026.000000
CURRENT_TIME
and
CURRENT_TIME()
are synonyms for
CURTIME()
.
CURRENT_TIMESTAMP
,
CURRENT_TIMESTAMP()
CURRENT_TIMESTAMP
and
CURRENT_TIMESTAMP()
are
synonyms for NOW()
.
Extracts the date part of the date or datetime expression
expr
.
mysql> SELECT DATE('2003-12-31 01:02:03');
-> '2003-12-31'
DATEDIFF()
returns
expr1
–
expr2
expressed as a value in days
from one date to the other. expr1
and expr2
are date or date-and-time
expressions. Only the date parts of the values are used in the
calculation.
mysql>SELECT DATEDIFF('2007-12-31 23:59:59','2007-12-30');
-> 1 mysql>SELECT DATEDIFF('2010-11-30 23:59:59','2010-12-31');
-> -31
DATE_ADD(
,
date
,INTERVAL
expr
unit
)DATE_SUB(
date
,INTERVAL
expr
unit
)
These functions perform date arithmetic. The
date
argument specifies the
starting date or datetime value.
expr
is an expression specifying
the interval value to be added or subtracted from the starting
date. expr
is a string; it may
start with a “-
” for negative
intervals. unit
is a keyword
indicating the units in which the expression should be
interpreted.
The INTERVAL
keyword and the
unit
specifier are not case
sensitive.
The following table shows the expected form of the
expr
argument for each
unit
value.
unit Value
|
Expected
expr
Format
|
MICROSECOND |
MICROSECONDS |
SECOND |
SECONDS |
MINUTE |
MINUTES |
HOUR |
HOURS |
DAY |
DAYS |
WEEK |
WEEKS |
MONTH |
MONTHS |
QUARTER |
QUARTERS |
YEAR |
YEARS |
SECOND_MICROSECOND |
'SECONDS.MICROSECONDS' |
MINUTE_MICROSECOND |
'MINUTES:SECONDS.MICROSECONDS' |
MINUTE_SECOND |
'MINUTES:SECONDS' |
HOUR_MICROSECOND |
'HOURS:MINUTES:SECONDS.MICROSECONDS' |
HOUR_SECOND |
'HOURS:MINUTES:SECONDS' |
HOUR_MINUTE |
'HOURS:MINUTES' |
DAY_MICROSECOND |
'DAYS HOURS:MINUTES:SECONDS.MICROSECONDS' |
DAY_SECOND |
'DAYS HOURS:MINUTES:SECONDS' |
DAY_MINUTE |
'DAYS HOURS:MINUTES' |
DAY_HOUR |
'DAYS HOURS' |
YEAR_MONTH |
'YEARS-MONTHS' |
The values QUARTER
and
WEEK
are available beginning with MySQL
5.0.0.
The return value depends on the arguments:
To ensure that the result is
DATETIME
, you can use
CAST()
to convert the first
argument to DATETIME
.
MySQL allows any punctuation delimiter in the
expr
format. Those shown in the
table are the suggested delimiters. If the
date
argument is a
DATE
value and your
calculations involve only YEAR
,
MONTH
, and DAY
parts
(that is, no time parts), the result is a
DATE
value. Otherwise, the
result is a DATETIME
value.
Date arithmetic also can be performed using
INTERVAL
together with the
+
or
-
operator:
date
+ INTERVALexpr
unit
date
- INTERVALexpr
unit
INTERVAL
is allowed on either
side of the expr
unit
+
operator if the expression on the other side is a date or
datetime value. For the
-
operator,
INTERVAL
is allowed only on
the right side, because it makes no sense to subtract a date
or datetime value from an interval.
expr
unit
mysql>SELECT '2008-12-31 23:59:59' + INTERVAL 1 SECOND;
-> '2009-01-01 00:00:00' mysql>SELECT INTERVAL 1 DAY + '2008-12-31';
-> '2009-01-01' mysql>SELECT '2005-01-01' - INTERVAL 1 SECOND;
-> '2004-12-31 23:59:59' mysql>SELECT DATE_ADD('2000-12-31 23:59:59',
->INTERVAL 1 SECOND);
-> '2001-01-01 00:00:00' mysql>SELECT DATE_ADD('2010-12-31 23:59:59',
->INTERVAL 1 DAY);
-> '2011-01-01 23:59:59' mysql>SELECT DATE_ADD('2100-12-31 23:59:59',
->INTERVAL '1:1' MINUTE_SECOND);
-> '2101-01-01 00:01:00' mysql>SELECT DATE_SUB('2005-01-01 00:00:00',
->INTERVAL '1 1:1:1' DAY_SECOND);
-> '2004-12-30 22:58:59' mysql>SELECT DATE_ADD('1900-01-01 00:00:00',
->INTERVAL '-1 10' DAY_HOUR);
-> '1899-12-30 14:00:00' mysql>SELECT DATE_SUB('1998-01-02', INTERVAL 31 DAY);
-> '1997-12-02' mysql>SELECT DATE_ADD('1992-12-31 23:59:59.000002',
->INTERVAL '1.999999' SECOND_MICROSECOND);
-> '1993-01-01 00:00:01.000001'
If you specify an interval value that is too short (does not
include all the interval parts that would be expected from the
unit
keyword), MySQL assumes that
you have left out the leftmost parts of the interval value.
For example, if you specify a unit
of DAY_SECOND
, the value of
expr
is expected to have days,
hours, minutes, and seconds parts. If you specify a value like
'1:10'
, MySQL assumes that the days and
hours parts are missing and the value represents minutes and
seconds. In other words, '1:10' DAY_SECOND
is interpreted in such a way that it is equivalent to
'1:10' MINUTE_SECOND
. This is analogous to
the way that MySQL interprets
TIME
values as representing
elapsed time rather than as a time of day.
Because expr
is treated as a
string, be careful if you specify a nonstring value with
INTERVAL
. For example, with an interval
specifier of HOUR_MINUTE
,
6/4
evaluates to 1.5000
and is treated as 1 hour, 5000 minutes:
mysql>SELECT 6/4;
-> 1.5000 mysql>SELECT DATE_ADD('2009-01-01', INTERVAL 6/4 HOUR_MINUTE);
-> '2009-01-04 12:20:00'
To ensure interpretation of the interval value as you expect,
a CAST()
operation may be used.
To treat 6/4
as 1 hour, 5 minutes, cast it
to a DECIMAL
value with a
single fractional digit:
mysql>SELECT CAST(6/4 AS DECIMAL(3,1));
-> 1.5 mysql>SELECT DATE_ADD('1970-01-01 12:00:00',
->INTERVAL CAST(6/4 AS DECIMAL(3,1)) HOUR_MINUTE);
-> '1970-01-01 13:05:00'
If you add to or subtract from a date value something that contains a time part, the result is automatically converted to a datetime value:
mysql>SELECT DATE_ADD('2013-01-01', INTERVAL 1 DAY);
-> '2013-01-02' mysql>SELECT DATE_ADD('2013-01-01', INTERVAL 1 HOUR);
-> '2013-01-01 01:00:00'
If you add MONTH
,
YEAR_MONTH
, or YEAR
and
the resulting date has a day that is larger than the maximum
day for the new month, the day is adjusted to the maximum days
in the new month:
mysql> SELECT DATE_ADD('2009-01-30', INTERVAL 1 MONTH);
-> '2009-02-28'
Date arithmetic operations require complete dates and do not
work with incomplete dates such as
'2006-07-00'
or badly malformed dates:
mysql>SELECT DATE_ADD('2006-07-00', INTERVAL 1 DAY);
-> NULL mysql>SELECT '2005-03-32' + INTERVAL 1 MONTH;
-> NULL
Formats the date
value according to
the format
string.
The following specifiers may be used in the
format
string. The
“%
” character is required
before format specifier characters.
Specifier | Description |
%a |
Abbreviated weekday name
(Sun ..Sat ) |
%b |
Abbreviated month name (Jan ..Dec ) |
%c |
Month, numeric (0 ..12 ) |
%D |
Day of the month with English suffix (0th ,
1st , 2nd ,
3rd , …) |
%d |
Day of the month, numeric (00 ..31 ) |
%e |
Day of the month, numeric (0 ..31 ) |
%f |
Microseconds (000000 ..999999 ) |
%H |
Hour (00 ..23 ) |
%h |
Hour (01 ..12 ) |
%I |
Hour (01 ..12 ) |
%i |
Minutes, numeric (00 ..59 ) |
%j |
Day of year (001 ..366 ) |
%k |
Hour (0 ..23 ) |
%l |
Hour (1 ..12 ) |
%M |
Month name (January ..December ) |
%m |
Month, numeric (00 ..12 ) |
%p |
AM or PM
|
%r |
Time, 12-hour (hh:mm:ss followed by
AM or PM ) |
%S |
Seconds (00 ..59 ) |
%s |
Seconds (00 ..59 ) |
%T |
Time, 24-hour (hh:mm:ss ) |
%U |
Week (00 ..53 ), where Sunday is the
first day of the week |
%u |
Week (00 ..53 ), where Monday is the
first day of the week |
%V |
Week (01 ..53 ), where Sunday is the
first day of the week; used with %X
|
%v |
Week (01 ..53 ), where Monday is the
first day of the week; used with %x
|
%W |
Weekday name (Sunday ..Saturday ) |
%w |
Day of the week
(0 =Sunday..6 =Saturday) |
%X |
Year for the week where Sunday is the first day of the week, numeric,
four digits; used with %V
|
%x |
Year for the week, where Monday is the first day of the week, numeric,
four digits; used with %v
|
%Y |
Year, numeric, four digits |
%y |
Year, numeric (two digits) |
%% |
A literal “% ” character |
% |
x , for any
“x ” not listed
above |
Ranges for the month and day specifiers begin with zero due to
the fact that MySQL allows the storing of incomplete dates
such as '2014-00-00'
.
As of MySQL 5.0.25, the language used for day and month names
and abbreviations is controlled by the value of the
lc_time_names
system variable
(Section 9.7, “MySQL Server Locale Support”).
As of MySQL 5.0.36,
DATE_FORMAT()
returns a string
with a character set and collation given by
character_set_connection
and
collation_connection
so that
it can return month and weekday names containing non-ASCII
characters. Before 5.0.36, the return value is a binary
string.
mysql>SELECT DATE_FORMAT('2009-10-04 22:23:00', '%W %M %Y');
-> 'Sunday October 2009' mysql>SELECT DATE_FORMAT('2007-10-04 22:23:00', '%H:%i:%s');
-> '22:23:00' mysql>SELECT DATE_FORMAT('1900-10-04 22:23:00',
->'%D %y %a %d %m %b %j');
-> '4th 00 Thu 04 10 Oct 277' mysql>SELECT DATE_FORMAT('1997-10-04 22:23:00',
->'%H %k %I %r %T %S %w');
-> '22 22 10 10:23:00 PM 22:23:00 00 6' mysql>SELECT DATE_FORMAT('1999-01-01', '%X %V');
-> '1998 52' mysql>SELECT DATE_FORMAT('2006-06-00', '%d');
-> '00'
DATE_SUB(
date
,INTERVAL
expr
unit
)
See the description for
DATE_ADD()
.
DAY()
is a synonym for
DAYOFMONTH()
.
Returns the name of the weekday for
date
. As of MySQL 5.0.25, the
language used for the name is controlled by the value of the
lc_time_names
system variable
(Section 9.7, “MySQL Server Locale Support”).
mysql> SELECT DAYNAME('2007-02-03');
-> 'Saturday'
Returns the day of the month for
date
, in the range
1
to 31
, or
0
for dates such as
'0000-00-00'
or
'2008-00-00'
that have a zero day part.
mysql> SELECT DAYOFMONTH('2007-02-03');
-> 3
Returns the weekday index for date
(1
= Sunday, 2
= Monday,
…, 7
= Saturday). These index values
correspond to the ODBC standard.
mysql> SELECT DAYOFWEEK('2007-02-03');
-> 7
Returns the day of the year for
date
, in the range
1
to 366
.
mysql> SELECT DAYOFYEAR('2007-02-03');
-> 34
The EXTRACT()
function uses the
same kinds of unit specifiers as
DATE_ADD()
or
DATE_SUB()
, but extracts parts
from the date rather than performing date arithmetic.
mysql>SELECT EXTRACT(YEAR FROM '2009-07-02');
-> 2009 mysql>SELECT EXTRACT(YEAR_MONTH FROM '2009-07-02 01:02:03');
-> 200907 mysql>SELECT EXTRACT(DAY_MINUTE FROM '2009-07-02 01:02:03');
-> 20102 mysql>SELECT EXTRACT(MICROSECOND
->FROM '2003-01-02 10:30:00.000123');
-> 123
Given a day number N
, returns a
DATE
value.
mysql> SELECT FROM_DAYS(730669);
-> '2007-07-03'
Use FROM_DAYS()
with caution on
old dates. It is not intended for use with values that precede
the advent of the Gregorian calendar (1582). See
Section 11.7, “What Calendar Is Used By MySQL?”.
FROM_UNIXTIME(
,
unix_timestamp
)FROM_UNIXTIME(
unix_timestamp
,format
)
Returns a representation of the
unix_timestamp
argument as a value
in 'YYYY-MM-DD HH:MM:SS'
or
YYYYMMDDHHMMSS.uuuuuu
format, depending on
whether the function is used in a string or numeric context.
The value is expressed in the current time zone.
unix_timestamp
is an internal
timestamp value such as is produced by the
UNIX_TIMESTAMP()
function.
If format
is given, the result is
formatted according to the format
string, which is used the same way as listed in the entry for
the DATE_FORMAT()
function.
mysql>SELECT FROM_UNIXTIME(1196440219);
-> '2007-11-30 10:30:19' mysql>SELECT FROM_UNIXTIME(1196440219) + 0;
-> 20071130103019.000000 mysql>SELECT FROM_UNIXTIME(UNIX_TIMESTAMP(),
->'%Y %D %M %h:%i:%s %x');
-> '2007 30th November 10:30:59 2007'
Note: If you use
UNIX_TIMESTAMP()
and
FROM_UNIXTIME()
to convert
between TIMESTAMP
values and
Unix timestamp values, the conversion is lossy because the
mapping is not one-to-one in both directions. For details, see
the description of the
UNIX_TIMESTAMP()
function.
GET_FORMAT({DATE|TIME|DATETIME},
{'EUR'|'USA'|'JIS'|'ISO'|'INTERNAL'})
Returns a format string. This function is useful in
combination with the
DATE_FORMAT()
and the
STR_TO_DATE()
functions.
The possible values for the first and second arguments result
in several possible format strings (for the specifiers used,
see the table in the
DATE_FORMAT()
function
description). ISO format refers to ISO 9075, not ISO 8601.
Function Call | Result |
GET_FORMAT(DATE,'USA') |
'%m.%d.%Y' |
GET_FORMAT(DATE,'JIS') |
'%Y-%m-%d' |
GET_FORMAT(DATE,'ISO') |
'%Y-%m-%d' |
GET_FORMAT(DATE,'EUR') |
'%d.%m.%Y' |
GET_FORMAT(DATE,'INTERNAL') |
'%Y%m%d' |
GET_FORMAT(DATETIME,'USA') |
'%Y-%m-%d %H.%i.%s' |
GET_FORMAT(DATETIME,'JIS') |
'%Y-%m-%d %H:%i:%s' |
GET_FORMAT(DATETIME,'ISO') |
'%Y-%m-%d %H:%i:%s' |
GET_FORMAT(DATETIME,'EUR') |
'%Y-%m-%d %H.%i.%s' |
GET_FORMAT(DATETIME,'INTERNAL') |
'%Y%m%d%H%i%s' |
GET_FORMAT(TIME,'USA') |
'%h:%i:%s %p' |
GET_FORMAT(TIME,'JIS') |
'%H:%i:%s' |
GET_FORMAT(TIME,'ISO') |
'%H:%i:%s' |
GET_FORMAT(TIME,'EUR') |
'%H.%i.%s' |
GET_FORMAT(TIME,'INTERNAL') |
'%H%i%s' |
TIMESTAMP
can also be used as
the first argument to
GET_FORMAT()
, in which case the
function returns the same values as for
DATETIME
.
mysql>SELECT DATE_FORMAT('2003-10-03',GET_FORMAT(DATE,'EUR'));
-> '03.10.2003' mysql>SELECT STR_TO_DATE('10.31.2003',GET_FORMAT(DATE,'USA'));
-> '2003-10-31'
Returns the hour for time
. The
range of the return value is 0
to
23
for time-of-day values. However, the
range of TIME
values actually
is much larger, so HOUR
can return values
greater than 23
.
mysql>SELECT HOUR('10:05:03');
-> 10 mysql>SELECT HOUR('272:59:59');
-> 272
Takes a date or datetime value and returns the corresponding
value for the last day of the month. Returns
NULL
if the argument is invalid.
mysql>SELECT LAST_DAY('2003-02-05');
-> '2003-02-28' mysql>SELECT LAST_DAY('2004-02-05');
-> '2004-02-29' mysql>SELECT LAST_DAY('2004-01-01 01:01:01');
-> '2004-01-31' mysql>SELECT LAST_DAY('2003-03-32');
-> NULL
LOCALTIME
and
LOCALTIME()
are synonyms for
NOW()
.
LOCALTIMESTAMP
,
LOCALTIMESTAMP()
LOCALTIMESTAMP
and
LOCALTIMESTAMP()
are synonyms
for NOW()
.
Returns a date, given year and day-of-year values.
dayofyear
must be greater than 0 or
the result is NULL
.
mysql>SELECT MAKEDATE(2011,31), MAKEDATE(2011,32);
-> '2011-01-31', '2011-02-01' mysql>SELECT MAKEDATE(2011,365), MAKEDATE(2014,365);
-> '2011-12-31', '2014-12-31' mysql>SELECT MAKEDATE(2011,0);
-> NULL
Returns a time value calculated from the
hour
,
minute
, and
second
arguments.
mysql> SELECT MAKETIME(12,15,30);
-> '12:15:30'
Returns the microseconds from the time or datetime expression
expr
as a number in the range from
0
to 999999
.
mysql>SELECT MICROSECOND('12:00:00.123456');
-> 123456 mysql>SELECT MICROSECOND('2009-12-31 23:59:59.000010');
-> 10
Returns the minute for time
, in the
range 0
to 59
.
mysql> SELECT MINUTE('2008-02-03 10:05:03');
-> 5
Returns the month for date
, in the
range 1
to 12
for
January to December, or 0
for dates such as
'0000-00-00'
or
'2008-00-00'
that have a zero month part.
mysql> SELECT MONTH('2008-02-03');
-> 2
Returns the full name of the month for
date
. As of MySQL 5.0.25, the
language used for the name is controlled by the value of the
lc_time_names
system variable
(Section 9.7, “MySQL Server Locale Support”).
mysql> SELECT MONTHNAME('2008-02-03');
-> 'February'
Returns the current date and time as a value in
'YYYY-MM-DD HH:MM:SS'
or
YYYYMMDDHHMMSS.uuuuuu
format, depending on
whether the function is used in a string or numeric context.
The value is expressed in the current time zone.
mysql>SELECT NOW();
-> '2007-12-15 23:50:26' mysql>SELECT NOW() + 0;
-> 20071215235026.000000
NOW()
returns a constant time
that indicates the time at which the statement began to
execute. (Within a stored function or trigger,
NOW()
returns the time at which
the function or triggering statement began to execute.) This
differs from the behavior for
SYSDATE()
, which returns the
exact time at which it executes as of MySQL 5.0.12.
mysql>SELECT NOW(), SLEEP(2), NOW();
+---------------------+----------+---------------------+ | NOW() | SLEEP(2) | NOW() | +---------------------+----------+---------------------+ | 2006-04-12 13:47:36 | 0 | 2006-04-12 13:47:36 | +---------------------+----------+---------------------+ mysql>SELECT SYSDATE(), SLEEP(2), SYSDATE();
+---------------------+----------+---------------------+ | SYSDATE() | SLEEP(2) | SYSDATE() | +---------------------+----------+---------------------+ | 2006-04-12 13:47:44 | 0 | 2006-04-12 13:47:46 | +---------------------+----------+---------------------+
In addition, the SET TIMESTAMP
statement
affects the value returned by
NOW()
but not by
SYSDATE()
. This means that
timestamp settings in the binary log have no effect on
invocations of SYSDATE()
.
See the description for
SYSDATE()
for additional
information about the differences between the two functions.
Adds N
months to period
P
(in the format
YYMM
or YYYYMM
). Returns
a value in the format YYYYMM
. Note that the
period argument P
is
not a date value.
mysql> SELECT PERIOD_ADD(200801,2);
-> 200803
Returns the number of months between periods
P1
and
P2
. P1
and P2
should be in the format
YYMM
or YYYYMM
. Note
that the period arguments P1
and
P2
are not
date values.
mysql> SELECT PERIOD_DIFF(200802,200703);
-> 11
Returns the quarter of the year for
date
, in the range
1
to 4
.
mysql> SELECT QUARTER('2008-04-01');
-> 2
Returns the second for time
, in the
range 0
to 59
.
mysql> SELECT SECOND('10:05:03');
-> 3
Returns the seconds
argument,
converted to hours, minutes, and seconds, as a
TIME
value. The range of the
result is constrained to that of the
TIME
data type. A warning
occurs if the argument corresponds to a value outside that
range.
mysql>SELECT SEC_TO_TIME(2378);
-> '00:39:38' mysql>SELECT SEC_TO_TIME(2378) + 0;
-> 3938
This is the inverse of the
DATE_FORMAT()
function. It
takes a string str
and a format
string format
.
STR_TO_DATE()
returns a
DATETIME
value if the format
string contains both date and time parts, or a
DATE
or
TIME
value if the string
contains only date or time parts. If the date, time, or
datetime value extracted from str
is illegal, STR_TO_DATE()
returns NULL
and, as of MySQL 5.0.3,
produces a warning.
The server scans str
attempting to
match format
to it. The format
string can contain literal characters and format specifiers
beginning with %
. Literal characters in
format
must match literally in
str
. Format specifiers in
format
must match a date or time
part in str
. For the specifiers
that can be used in format
, see the
DATE_FORMAT()
function
description.
mysql>SELECT STR_TO_DATE('01,5,2013','%d,%m,%Y');
-> '2013-05-01' mysql>SELECT STR_TO_DATE('May 1, 2013','%M %d,%Y');
-> '2013-05-01'
Scanning starts at the beginning of
str
and fails if
format
is found not to match. Extra
characters at the end of str
are
ignored.
mysql>SELECT STR_TO_DATE('a09:30:17','a%h:%i:%s');
-> '09:30:17' mysql>SELECT STR_TO_DATE('a09:30:17','%h:%i:%s');
-> NULL mysql>SELECT STR_TO_DATE('09:30:17a','%h:%i:%s');
-> '09:30:17'
Unspecified date or time parts have a value of 0, so
incompletely specified values in
str
produce a result with some or
all parts set to 0:
mysql>SELECT STR_TO_DATE('abc','abc');
-> '0000-00-00' mysql>SELECT STR_TO_DATE('9','%m');
-> '0000-09-00' mysql>SELECT STR_TO_DATE('9','%s');
-> '00:00:09'
Range checking on the parts of date values is as described in
Section 10.3.1, “The DATETIME
,
DATE
, and
TIMESTAMP
Types”. This means, for example, that
“zero” dates or dates with part values of 0 are
allowed unless the SQL mode is set to disallow such values.
mysql>SELECT STR_TO_DATE('00/00/0000', '%m/%d/%Y');
-> '0000-00-00' mysql>SELECT STR_TO_DATE('04/31/2004', '%m/%d/%Y');
-> '2004-04-31'
You cannot use format "%X%V"
to convert a
year-week string to a date because the combination of a year
and week does not uniquely identify a year and month if the
week crosses a month boundary. To convert a year-week to a
date, then you should also specify the weekday:
mysql> SELECT STR_TO_DATE('200442 Monday', '%X%V %W');
-> '2004-10-18'
SUBDATE(
,
date
,INTERVAL
expr
unit
)SUBDATE(
expr
,days
)
When invoked with the INTERVAL
form of the
second argument, SUBDATE()
is a
synonym for DATE_SUB()
. For
information on the INTERVAL
unit
argument, see the discussion
for DATE_ADD()
.
mysql>SELECT DATE_SUB('2008-01-02', INTERVAL 31 DAY);
-> '2007-12-02' mysql>SELECT SUBDATE('2008-01-02', INTERVAL 31 DAY);
-> '2007-12-02'
The second form allows the use of an integer value for
days
. In such cases, it is
interpreted as the number of days to be subtracted from the
date or datetime expression expr
.
mysql> SELECT SUBDATE('2008-01-02 12:00:00', 31);
-> '2007-12-02 12:00:00'
SUBTIME()
returns
expr1
–
expr2
expressed as a value in the
same format as expr1
.
expr1
is a time or datetime
expression, and expr2
is a time
expression.
mysql>SELECT SUBTIME('2007-12-31 23:59:59.999999','1 1:1:1.000002');
-> '2007-12-30 22:58:58.999997' mysql>SELECT SUBTIME('01:00:00.999999', '02:00:00.999998');
-> '-00:59:59.999999'
Returns the current date and time as a value in
'YYYY-MM-DD HH:MM:SS'
or
YYYYMMDDHHMMSS.uuuuuu
format, depending on
whether the function is used in a string or numeric context.
As of MySQL 5.0.12, SYSDATE()
returns the time at which it executes. This differs from the
behavior for NOW()
, which
returns a constant time that indicates the time at which the
statement began to execute. (Within a stored function or
trigger, NOW()
returns the time
at which the function or triggering statement began to
execute.)
mysql>SELECT NOW(), SLEEP(2), NOW();
+---------------------+----------+---------------------+ | NOW() | SLEEP(2) | NOW() | +---------------------+----------+---------------------+ | 2006-04-12 13:47:36 | 0 | 2006-04-12 13:47:36 | +---------------------+----------+---------------------+ mysql>SELECT SYSDATE(), SLEEP(2), SYSDATE();
+---------------------+----------+---------------------+ | SYSDATE() | SLEEP(2) | SYSDATE() | +---------------------+----------+---------------------+ | 2006-04-12 13:47:44 | 0 | 2006-04-12 13:47:46 | +---------------------+----------+---------------------+
In addition, the SET TIMESTAMP
statement
affects the value returned by
NOW()
but not by
SYSDATE()
. This means that
timestamp settings in the binary log have no effect on
invocations of SYSDATE()
.
Because SYSDATE()
can return
different values even within the same statement, and is not
affected by SET TIMESTAMP
, it is
nondeterministic and therefore unsafe for replication. If that
is a problem, you can start the server with the
--sysdate-is-now
option to
cause SYSDATE()
to be an alias
for NOW()
. The nondeterministic
nature of SYSDATE()
also means
that indexes cannot be used for evaluating expressions that
refer to it.
Extracts the time part of the time or datetime expression
expr
and returns it as a string.
mysql>SELECT TIME('2003-12-31 01:02:03');
-> '01:02:03' mysql>SELECT TIME('2003-12-31 01:02:03.000123');
-> '01:02:03.000123'
TIMEDIFF()
returns
expr1
–
expr2
expressed as a time value.
expr1
and
expr2
are time or date-and-time
expressions, but both must be of the same type.
mysql>SELECT TIMEDIFF('2000:01:01 00:00:00',
->'2000:01:01 00:00:00.000001');
-> '-00:00:00.000001' mysql>SELECT TIMEDIFF('2008-12-31 23:59:59.000001',
->'2008-12-30 01:01:01.000002');
-> '46:58:57.999999'
TIMESTAMP(
,
expr
)TIMESTAMP(
expr1
,expr2
)
With a single argument, this function returns the date or
datetime expression expr
as a
datetime value. With two arguments, it adds the time
expression expr2
to the date or
datetime expression expr1
and
returns the result as a datetime value.
mysql>SELECT TIMESTAMP('2003-12-31');
-> '2003-12-31 00:00:00' mysql>SELECT TIMESTAMP('2003-12-31 12:00:00','12:00:00');
-> '2004-01-01 00:00:00'
TIMESTAMPADD(
unit
,interval
,datetime_expr
)
Adds the integer expression
interval
to the date or datetime
expression datetime_expr
. The unit
for interval
is given by the
unit
argument, which should be one
of the following values: FRAC_SECOND
(microseconds), SECOND
,
MINUTE
, HOUR
,
DAY
, WEEK
,
MONTH
, QUARTER
, or
YEAR
.
Beginning with MySQL 5.0.60, it is possible to use
MICROSECOND
in place of
FRAC_SECOND
with this function, and
FRAC_SECOND
is deprecated.
FRAC_SECOND
is removed in MySQL 5.5.
The unit
value may be specified
using one of keywords as shown, or with a prefix of
SQL_TSI_
. For example,
DAY
and SQL_TSI_DAY
both
are legal.
mysql>SELECT TIMESTAMPADD(MINUTE,1,'2003-01-02');
-> '2003-01-02 00:01:00' mysql>SELECT TIMESTAMPADD(WEEK,1,'2003-01-02');
-> '2003-01-09'
TIMESTAMPADD()
is available as
of MySQL 5.0.0.
TIMESTAMPDIFF(
unit
,datetime_expr1
,datetime_expr2
)
Returns
,
where datetime_expr2
– datetime_expr1
datetime_expr1
and
datetime_expr2
are date or datetime
expressions. One expression may be a date and the other a
datetime; a date value is treated as a datetime having the
time part '00:00:00'
where necessary. The
unit for the result (an integer) is given by the
unit
argument. The legal values for
unit
are the same as those listed
in the description of the
TIMESTAMPADD()
function.
mysql>SELECT TIMESTAMPDIFF(MONTH,'2003-02-01','2003-05-01');
-> 3 mysql>SELECT TIMESTAMPDIFF(YEAR,'2002-05-01','2001-01-01');
-> -1 mysql>SELECT TIMESTAMPDIFF(MINUTE,'2003-02-01','2003-05-01 12:05:55');
-> 128885
TIMESTAMPDIFF()
is available as
of MySQL 5.0.0.
The order of the date or datetime arguments for this
function is the opposite of that used with the
TIMESTAMP()
function when
invoked with 2 arguments.
This is used like the
DATE_FORMAT()
function, but the
format
string may contain format
specifiers only for hours, minutes, seconds, and microseconds.
Other specifiers produce a NULL
value or
0
.
If the time
value contains an hour
part that is greater than 23
, the
%H
and %k
hour format
specifiers produce a value larger than the usual range of
0..23
. The other hour format specifiers
produce the hour value modulo 12.
mysql> SELECT TIME_FORMAT('100:00:00', '%H %k %h %I %l');
-> '100 100 04 04 4'
Returns the time
argument,
converted to seconds.
mysql>SELECT TIME_TO_SEC('22:23:00');
-> 80580 mysql>SELECT TIME_TO_SEC('00:39:38');
-> 2378
Given a date date
, returns a day
number (the number of days since year 0).
mysql>SELECT TO_DAYS(950501);
-> 728779 mysql>SELECT TO_DAYS('2007-10-07');
-> 733321
TO_DAYS()
is not intended for
use with values that precede the advent of the Gregorian
calendar (1582), because it does not take into account the
days that were lost when the calendar was changed. For dates
before 1582 (and possibly a later year in other locales),
results from this function are not reliable. See
Section 11.7, “What Calendar Is Used By MySQL?”, for details.
Remember that MySQL converts two-digit year values in dates to
four-digit form using the rules in
Section 10.3, “Date and Time Types”. For example,
'2008-10-07'
and
'08-10-07'
are seen as identical dates:
mysql> SELECT TO_DAYS('2008-10-07'), TO_DAYS('08-10-07');
-> 733687, 733687
In MySQL, the zero date is defined as
'0000-00-00'
, even though this date is
itself considered invalid. This means that, for
'0000-00-00'
and
'0000-01-01'
,
TO_DAYS()
returns the values
shown here:
mysql>SELECT TO_DAYS('0000-00-00');
+-----------------------+ | to_days('0000-00-00') | +-----------------------+ | NULL | +-----------------------+ 1 row in set, 1 warning (0.00 sec) mysql>SHOW WARNINGS;
+---------+------+----------------------------------------+ | Level | Code | Message | +---------+------+----------------------------------------+ | Warning | 1292 | Incorrect datetime value: '0000-00-00' | +---------+------+----------------------------------------+ 1 row in set (0.00 sec) mysql>SELECT TO_DAYS('0000-01-01');
+-----------------------+ | to_days('0000-01-01') | +-----------------------+ | 1 | +-----------------------+ 1 row in set (0.00 sec)
This is true whether or not the
ALLOW_INVALID_DATES
SQL
server mode (available in MySQL 5.0.2 and later) is enabled.
UNIX_TIMESTAMP()
,
UNIX_TIMESTAMP(
date
)
If called with no argument, returns a Unix timestamp (seconds
since '1970-01-01 00:00:00'
UTC) as an
unsigned integer. If
UNIX_TIMESTAMP()
is called with
a date
argument, it returns the
value of the argument as seconds since '1970-01-01
00:00:00'
UTC. date
may
be a DATE
string, a
DATETIME
string, a
TIMESTAMP
, or a number in the
format YYMMDD
or
YYYYMMDD
. The server interprets
date
as a value in the current time
zone and converts it to an internal value in UTC. Clients can
set their time zone as described in
Section 9.6, “MySQL Server Time Zone Support”.
mysql>SELECT UNIX_TIMESTAMP();
-> 1196440210 mysql>SELECT UNIX_TIMESTAMP('2007-11-30 10:30:19');
-> 1196440219
When UNIX_TIMESTAMP()
is used
on a TIMESTAMP
column, the
function returns the internal timestamp value directly, with
no implicit “string-to-Unix-timestamp”
conversion. If you pass an out-of-range date to
UNIX_TIMESTAMP()
, it returns
0
.
Note: If you use
UNIX_TIMESTAMP()
and
FROM_UNIXTIME()
to convert
between TIMESTAMP
values and
Unix timestamp values, the conversion is lossy because the
mapping is not one-to-one in both directions. For example, due
to conventions for local time zone changes, it is possible for
two UNIX_TIMESTAMP()
to map two
TIMESTAMP
values to the same
Unix timestamp value.
FROM_UNIXTIME()
will map that
value back to only one of the original
TIMESTAMP
values. Here is an
example, using TIMESTAMP
values
in the CET
time zone:
mysql>SELECT UNIX_TIMESTAMP('2005-03-27 03:00:00');
+---------------------------------------+ | UNIX_TIMESTAMP('2005-03-27 03:00:00') | +---------------------------------------+ | 1111885200 | +---------------------------------------+ mysql>SELECT UNIX_TIMESTAMP('2005-03-27 02:00:00');
+---------------------------------------+ | UNIX_TIMESTAMP('2005-03-27 02:00:00') | +---------------------------------------+ | 1111885200 | +---------------------------------------+ mysql>SELECT FROM_UNIXTIME(1111885200);
+---------------------------+ | FROM_UNIXTIME(1111885200) | +---------------------------+ | 2005-03-27 03:00:00 | +---------------------------+
If you want to subtract
UNIX_TIMESTAMP()
columns, you
might want to cast the result to signed integers. See
Section 11.9, “Cast Functions and Operators”.
Returns the current UTC date as a value in
'YYYY-MM-DD'
or YYYYMMDD
format, depending on whether the function is used in a string
or numeric context.
mysql> SELECT UTC_DATE(), UTC_DATE() + 0;
-> '2003-08-14', 20030814
Returns the current UTC time as a value in
'HH:MM:SS'
or
HHMMSS.uuuuuu
format, depending on whether
the function is used in a string or numeric context.
mysql> SELECT UTC_TIME(), UTC_TIME() + 0;
-> '18:07:53', 180753.000000
UTC_TIMESTAMP
,
UTC_TIMESTAMP()
Returns the current UTC date and time as a value in
'YYYY-MM-DD HH:MM:SS'
or
YYYYMMDDHHMMSS.uuuuuu
format, depending on
whether the function is used in a string or numeric context.
mysql> SELECT UTC_TIMESTAMP(), UTC_TIMESTAMP() + 0;
-> '2003-08-14 18:08:04', 20030814180804.000000
This function returns the week number for
date
. The two-argument form of
WEEK()
allows you to specify
whether the week starts on Sunday or Monday and whether the
return value should be in the range from 0
to 53
or from 1
to
53
. If the mode
argument is omitted, the value of the
default_week_format
system
variable is used. See
Section 5.1.3, “Server System Variables”.
The following table describes how the
mode
argument works.
Mode | First day of week | Range | Week 1 is the first week … |
0 | Sunday | 0-53 | with a Sunday in this year |
1 | Monday | 0-53 | with more than 3 days this year |
2 | Sunday | 1-53 | with a Sunday in this year |
3 | Monday | 1-53 | with more than 3 days this year |
4 | Sunday | 0-53 | with more than 3 days this year |
5 | Monday | 0-53 | with a Monday in this year |
6 | Sunday | 1-53 | with more than 3 days this year |
7 | Monday | 1-53 | with a Monday in this year |
mysql>SELECT WEEK('2008-02-20');
-> 7 mysql>SELECT WEEK('2008-02-20',0);
-> 7 mysql>SELECT WEEK('2008-02-20',1);
-> 8 mysql>SELECT WEEK('2008-12-31',1);
-> 53
Note that if a date falls in the last week of the previous
year, MySQL returns 0
if you do not use
2
, 3
,
6
, or 7
as the optional
mode
argument:
mysql> SELECT YEAR('2000-01-01'), WEEK('2000-01-01',0);
-> 2000, 0
One might argue that MySQL should return 52
for the WEEK()
function,
because the given date actually occurs in the 52nd week of
1999. We decided to return 0
instead
because we want the function to return “the week number
in the given year.” This makes use of the
WEEK()
function reliable when
combined with other functions that extract a date part from a
date.
If you would prefer the result to be evaluated with respect to
the year that contains the first day of the week for the given
date, use 0
, 2
,
5
, or 7
as the optional
mode
argument.
mysql> SELECT WEEK('2000-01-01',2);
-> 52
Alternatively, use the
YEARWEEK()
function:
mysql>SELECT YEARWEEK('2000-01-01');
-> 199952 mysql>SELECT MID(YEARWEEK('2000-01-01'),5,2);
-> '52'
Returns the weekday index for date
(0
= Monday, 1
=
Tuesday, … 6
= Sunday).
mysql>SELECT WEEKDAY('2008-02-03 22:23:00');
-> 6 mysql>SELECT WEEKDAY('2007-11-06');
-> 1
Returns the calendar week of the date as a number in the range
from 1
to 53
.
WEEKOFYEAR()
is a compatibility
function that is equivalent to
WEEK(
.
date
,3)
mysql> SELECT WEEKOFYEAR('2008-02-20');
-> 8
Returns the year for date
, in the
range 1000
to 9999
, or
0
for the “zero” date.
mysql> SELECT YEAR('1987-01-01');
-> 1987
YEARWEEK(
,
date
)YEARWEEK(
date
,mode
)
Returns year and week for a date. The
mode
argument works exactly like
the mode
argument to
WEEK()
. The year in the result
may be different from the year in the date argument for the
first and the last week of the year.
mysql> SELECT YEARWEEK('1987-01-01');
-> 198653
Note that the week number is different from what the
WEEK()
function would return
(0
) for optional arguments
0
or 1
, as
WEEK()
then returns the week in
the context of the given year.
User Comments
If you're looking for generic SQL queries that will allow you to get the days, months, and years between any two given dates, you might consider using these. You just need to substitute date1 and date2 with your date expressions.
NOTE: Some of these formulas are complex because they account for all cases where date1 < date2, date1 = date2, and date1 > date2. Additionally, these formulas can be used in very generic queries where aliases and temporary variables are not allowed.
Number of days between date1 and date2:
TO_DAYS(date2) - TO_DAYS(date1)
Number of months between date1 and date2:
IF((((YEAR(date2) - 1) * 12 + MONTH(date2)) - ((YEAR(date1) - 1) * 12 + MONTH(date1))) > 0, (((YEAR(date2) - 1) * 12 + MONTH(date2)) - ((YEAR(date1) - 1) * 12 + MONTH(date1))) - (MID(date2, 9, 2) < MID(date1, 9, 2)), IF((((YEAR(date2) - 1) * 12 + MONTH(date2)) - ((YEAR(date1) - 1) * 12 + MONTH(date1))) < 0, (((YEAR(date2) - 1) * 12 + MONTH(date2)) - ((YEAR(date1) - 1) * 12 + MONTH(date1))) + (MID(date1, 9, 2) < MID(date2, 9, 2)), (((YEAR(date2) - 1) * 12 + MONTH(date2)) - ((YEAR(date1) - 1) * 12 + MONTH(date1)))))
Number of years between date1 and date2:
IF((YEAR(date2) - YEAR(date1)) > 0, (YEAR(date2) - YEAR(date1)) - (MID(date2, 6, 5) < MID(date1, 6, 5)), IF((YEAR(date2) - YEAR(date1)) < 0, (YEAR(date2) - YEAR(date1)) + (MID(date1, 6, 5) < MID(date2, 6, 5)), (YEAR(date2) - YEAR(date1))))
Now for some comments about these.
1. These results return integer number of years, months, and days. They are "floored." Thus, 1.4 days would display as 1 day, and 13.9 years would display as 13 years. Likewise, -1.4 years would display as -1 year, and -13.9 months would display as -13 months.
2. Note that I use boolean expressions in many cases. Because boolean expressions evaluate to 0 or 1, I can use them to subtract or add 1 from the total based on a condition.
For example, to calculate the number of years between to dates, first simply subtract the years. The problem is that doing so isn't always correct. Consider the number of years between July 1, 1950 and May 1, 1952. Technically, there is only one full year between them. On July 1, 1952 and later, there will be two years. Therefore, you should subtract one year in case the date hasn't yet reached a full year. This is done by checking the if the second month-day is before the first month-
day. If so, this results in a value of 1, which is subtracted from the total. The IF statements are in the formula because we must add one year when dealing with the dates in the opposite order, and we must not add or subtract anything when the difference of the date years is zero.
3. To get the month-day, I use MID. This is better
than using RIGHT, since it will work for both dates
and datetimes.
4. Unlike many other solutions, these queries should
work with dates prior to 01/01/1970.
Spent some time trying to work out how to calculate the month start x months ago ( so that I can create historical stats on the fly)
here is what I came up with..
((PERIOD_ADD(EXTRACT(YEAR_MONTH FROM CURDATE()),-6)*100)+1)
this gives you the first day of the month six months before the start of the current month in datetime format
Several times i have come to a followng date/time problem:
In the table i am storing both date and time information in the datetime column. Querying, I want to receive COUNTed results grouped by date, and not date and time. I came to the easy solution:
SELECT DATE_FORMAT(postdate, '%Y-%m-%d') AS dd, COUNT(id) FROM MyTable GROUP BY dd;
I suppose this solution to be quite slow (date formatting).
Later, i 'upgraded' this query to use the string function:
SELECT substring(postdate, 1,10) AS dd, COUNT(id) FROM MyTable GROUP BY dd;
knowing, that the result is in the fixed format. Works faster.
Hope this will help somebody. The way I found to sum time:
SELECT SEC_TO_TIME( SUM( TIME_TO_SEC( `time` ) ) ) AS total_time FROM time_table;
Comparing Dates when using MS Access and MyODBC
If you are using MS Access and have created Access queries to substitute for views (which are not yet available in mySQL), you can use the following syntax ro perform date comparisons and avoid the dreaded "ODBC -- call failed" error:
Select * from [Task Effort Summary]
Where ((Date() + 0) > CLng([Task Effort Summary].[s_end]))
This particular example retuns tasks that are overdue (where todays date is past the scheduled end date). This query was developed for reports on a TUTOS database.
Note that the built-in default values for the DATE and DATEFIELD column types is out of range. For example, 0000-00-00 is a valid way of expressing NULL, but if the column is set as NOT NULL, 0000-00-00 is still the default value. This can cause problems with some applications using MySQL.
I was looking for a function to detect if the current week is odd or even. I could not find one so I use this:
MOD((DATE_FORMAT(CURDATE(),"%v")),2)
The output is a '0'(even) or a '1'(odd)
To create a DATETIME of NOW() in UTC without upgrading to 4.1.1, just use:
DATE_ADD( '1970-01-01', INTERVAL UNIX_TIMESTAMP() SECOND )
workaround for STR_TO_DATE pre version 4.1.1. ugly but it seems to work fine.
assumption: you know the format of the received date (in the below example the format is mm/dd/yy, m/d/yy, mm/dd/yyyy, etc)
the statement extracts the year by locating the index of the second '/' and reading from the right of the string to that index. the index of the second is '/' is found by using LOCATE with the index of the first '/'.
it extracts the day by locating the indeces of the first and second '/' and reading between them
it extracts the month by locating the index of the first '/' and reading from the left of the string to that index.
it then CONCATs the year month and day pieces together separating them with hyphens.
lastly, it lets DATE_FORMAT do its magic on the string.
(replace the test string '1/11/03' with your field name, etc)
select DATE_FORMAT( CONCAT( RIGHT( '1/11/03' , length( '1/11/03') - LOCATE('/', '1/11/03' , LOCATE('/', '1/11/03' ) + 1 ) ) , '-' , LEFT( '1/11/03' , LOCATE('/', '1/11/03' ) - 1 ) , '-', SUBSTRING( '1/11/03' , LOCATE('/', '1/11/03' ) + 1, LOCATE('/', '1/11/03' , LOCATE('/', '1/11/03' ) + 1 ) - LOCATE('/', '1/11/03' ) - 1 ) ) , '%Y-%m-%d' )
Lets say you have the mysql before 4.1.1 (where timediff() was implementet), and you want to do a timediff.
I wanted to make a "active users" on my page, but I found out that I didnt have the timediff function (to find persons which have been active within 5 minutes).
So, I figured this query out:
SELECT nick FROM `users` WHERE TO_DAYS( NOW( ) ) - TO_DAYS( last_login ) <=1 AND DATE_FORMAT( CURRENT_TIMESTAMP( ) , '%H%i' ) - DATE_FORMAT( last_login, '%H%i' ) <=5 ORDER BY `nick` ASC;
it selects the field nick (which is the only one to be displayd) and then it filters for 1 day or less in age of activity. after that, it filters for 5 minutes or less in activity.
first you need to filter away the other days, or your script might get fooled to think that yesterdays login was todays.
I'm currently using this, and it works fine!
on the other page, you of course need to update the timestamp field (when session excists, on reload)
Here is an example to convert various user inputs for a date field on an ASP page (VBScript) that will convert common formats (i.e., m/d/yy, mm/dd/yyyy, etc.) to MySQL database format of (yyyy-mm-dd). The function begins by establishing that there is a date in the field. Then splits the date (converted to string) into three parts by locating "/". DateArray(0), DateArray(1), DateArray(2) hold the month, day and year, respectively. These are then checked for the amount of digits, if there are not enough digits in month or day then a leading zero is added. If there are only two digits on the year (ie "04") then a leading "20" is added.
Function ConvertInputDate(varDate)
If (Len(Trim(varDate)) > 0) Then
DateArray=Split(CStr(varDate),"/")
IF Len(Trim(DateArray(0))) < 2 Then
DateArray(0) = "0" & DateArray(0)
End If
If Len(Trim(DateArray(1))) < 2 Then
DateArray(1) = "0" & DateArray(1)
End If
If Len(Trim(DateArray(2))) < 4 Then DateArray(2) = "20" & DateArray(2)
End If
varDate = DateArray(2) & "-" & DateArray(0) & "-" & DateArray(1)
End If
End Function
*Please note if a user does not use two slashes this function will not work. It is best to indicate "mm/dd/yy" near the label on the page. It will take 4/6/04, 10/6/04, 3/16/2004 and all combinations with two slashes.
I had a problem with my login script using PHP and MySQL when daylight savings time (DST) came around this year.
I was using MYSQL NOW() function to add the current date and time to the user's record into a datetime field. When DST came into effect newly entered login times were an hour slow (I'm in EST). Since the last login is to be updated only if an hour or more has passed since the last login this was a big problem!
The problem is that PHP takes DST into account and MySQL does not (as far as I know) and I was entering the time using MySQL's NOW() function and then comparing the value returned by PHP's time() function.
A very simple solution to this is the following. Note the PHP time format string 'YmdHis' - it formats to YYYYMMDDHHMMSS which is what MySQL expects for a date/time field.
$now = time();
$lastLogin = strtotime($row['lastLogin']);
$diff = $now - $lastLogin;
$now = date('YmdHis',$now)
if($diff > 3600) { // 3600 seconds is 1 hour
$query = 'UPDATE members SET logins = logins + 1, lastLogin = '.$now.' WHERE memberID = '.$SEC_ID;
mysql_query($query);
}
Now the date entered is the PHP time (that accounts for DST) and we are comparing it to PHP time so all is well.
I think this approach will work well for any time you wish to enter a date into MySQL using PHP. Just format the date using the "YmdHis" format string and use the strtotime() function to read a date retrieved from MySQL.
The advantage to this approach rather than just entering the "normal" PHP date into a char or text field is that the dates are "human" readable in the table and all the MySQL date/time functions are available for future queries.
to localize the weekday:
SELECT ELT( WEEKDAY('2004-04-10')+1, 'Montag','Dienstag','Mittwoch','Donnerstag','Freitag','Samstag','Sonntag');
long version with month:
SELECT DATE_FORMAT( '2004-04-10', CONCAT( ELT( WEEKDAY('2004-04-10')+1, 'Montag','Dienstag','Mittwoch','Donnerstag','Freitag','Samstag','Sonntag'),', %d. ', ELT( MONTH('2004-04-10'), 'Januar','Februar','März','April','Mai','Juni','Juli','August','September','Oktober','November','Dezember'),' %Y'));
--> Samstag, 10. April 2004
same for unix-timestamp:
SELECT DATE_FORMAT( FROM_UNIXTIME(1081548000), CONCAT( ELT( WEEKDAY(FROM_UNIXTIME(1081548000))+1, 'Mo','Di','Mi','Do','Fr','Sa','So'),', %d. ', ELT( MONTH(FROM_UNIXTIME(1081548000)), 'Jan.','Feb.','März','April','Mai','Juni','Juli','Aug.','Sept.','Okt.','Nov.','Dez.'),' %Y'));
--> Sa, 10. April 2004
I had to query a table and retrieve rows that were added only today, so :
select id from my_table
where
timestamp < date_format(date_add(CURRENT_TIMESTAMP(), interval 1 day),'%Y%m%d000000')
AND
timestamp >= date_format(CURRENT_TIMESTAMP(),'%Y%m%d000000')
starting with MySQL 4.0, you could also use the BETWEEN ... AND syntax.
If anyone has a better query to do that, let me know.
After reading numerous articles and posts regarding converting back and forth between SQL datetime and VBscript datetime, I opted for the simplest solution for my databases. I simply save all datetime values in varchar(20) fields and call on either MySQL or VBscript functions to get datetime values or check/convert datetime values. For example:
currentDT = CStr(cn.execute("SELECT NOW()").Fields(0).Value)
will fetch current datetime in the SQL server's datetime format and then convert it to a string. [Obviously, cn is set by Set cn = Server.CreateObject("ADODB.Connection") to create the database connection, then the database is opened with a cn.open (parameters).]
You can then save this string to an appropriate field such as 'flddate_added' which is formatted as varchar(20).
When retrieving the flddate_added value, you can use this VBscript code to check if the value is indeed a datetime value and convert it to the datetime format of the user's computer"
if IsDate(flddate_added) then
=CDate(flddate_added) ' convert to user's system format for display using user's codepage
else
=flddate_added ' just display the string
end if
The above methods allow me to get around all of the issues regarding VBscript's datetime display format differences depending on the system local.
Posted by Filip Wolak:
> Several times i have come to a followng date/time problem:
> In the table i am storing both date and time information in the datetime
> column. Querying, I want to receive COUNTed results grouped by date,
> and not date and time.
...
> SELECT substring(postdate, 1,10) ...
If it's a DATETIME column than substring is not appropriate -
it's logically nonsensical of course, and just happens to work
in some version of MySQL because the DATETIME happens
to be represented by a string in some contexts.
Better would be to treat the DATETIME as a DATETIME
rather than as a string, which will work in future versions
of MYSQL and in other RDMS:
SELECT DATE(postdate) ...
Here is another VB/ASP function for converting Dates from standard to MySQL format. Cherise gave a nice example above, but it has extra complexity due to the use of arrays and also may be proned to user input errors.
The following example will work based on the Localization settings of the server on which it is run. So it shouldn't care whether the date is dd-mm-yyyy, mm/dd/yy, mm/dd/yyyy, m-d-yy, etc. Just make sure you pass it a date value that is formatted compliant to the server's localization. If necessary use VB's CDate(strDateValue) before passing strDateValue to the function.
You can also easily modify this function to do the same for Time values, except you use Hour, Minute, and Second VB functions, and delimit with a colon (:) instead of a dash (-).
Hope this helps!
Function funcMySqlDate(dtmChangeDate)
'CONVERTS LOCALIZED DATE FORMAT (for example: m/d/yy) TO MySQL FORMAT (yyyy-mm-dd)
Dim strTempYear, strTempMonth, strTempDay
strTempYear = Year(dtmChangeDate)
strTempMonth = Month(dtmChangeDate)
strTempDay = Day(dtmChangeDate)
if Len(strTempYear) = 2 then 'Y2K TEST - 1938-2037 - ADJUST AS NECESSARY
if strTempYear >= 38 then
strTempYear = "19" & strTempYear
else
strTempYear = "20" & strTempYear
end if
end if
if strTempMonth < 10 then strTempMonth = "0" & strTempMonth
if strTempDay < 10 then strTempDay = "0" & strTempDay
funcMySqlDate = strTempYear & "-" & strTempMonth & "-" & strTempDay
End Function
To find out the last day of a month use:
SELECT (DATE_FORMAT('2004-01-20' ,'%Y-%m-01') - INTERVAL 1 DAY) + INTERVAL 1 MONTH;
It tooks me a few time to have this idea, but it works. If you want to have the first day of a month use:
SELECT DATE_FORMAT('2004-01-20' ,'%Y-%m-01');
To find out the first day of a month was my first development step, then it was easy to extract the last day of a month. It is usefull for accounting for services where I need this solution.
Greetings
I see the use for both, but I find this layout more useful as a reference tool:
Select records that are older than X days from the current date where sent_time is a Timestamp datatype field.
select ID from MESSAGE where SENT_TIME < (CURDATE() - INTERVAL 5 DAY);
If you do not have 4.xx yet here is a simple way to get the last day of the month. You can replace the current date with a var to find the last day of any month.
SELECT
SUBDATE( ADDDATE( CURDATE(), INTERVAL 1 MONTH), INTERVAL DAYOFMONTH( CURDATE() ) DAY) AS LAST_DAY_MONTH
seems to work well .
>Several times i have come to a followng date/time problem:
>In the table i am storing both date and time information in the
>datetime column. Querying, I want to receive COUNTed results
>grouped by date, and not date and time. I came to the easy
>solution:
I needed a query for a more general case to do time based reporting on arbitrary big "slices" of timestamped data.
My table has a column 'timestamp' which is of type 'datetime'.
The following makes '120' second big slices
select from_unixtime(unix_timestamp(timestamp) - unix_timestamp(timestamp) % 120) as slice, ... group by slice;
I wanted to find the start date (Sunday) and the end date (Saturday) for any given week when all I had to go from is an arbitrary date (more precisely, the current date). Since MySQL registers Sunday as 1, and Saturday as 7, if you wish to adjust the start and end points on a week, you'll have to modify the following function calls appropriately, and change the integers, or (as I have done) use variables:
set @someday = curdate();
set @weekstart = 1; // Sunday
set @weekend = 7; // Saturday
end of week:
select date_add(@someday, interval @weekend-dayofweek(@someday) day);
beginning of week:
select date_sub(@someday, interval dayofweek(@someday)-@weekstart day);
Of course, I use these functions in a more complex query that filters select results from a table with a "datetime" field. This allows me to focus on weekly data. A very neat thing is being able to replace 'curdate()' with a date at (theoretically) any point in time on the Gregorian calendar.
The value returned by
UNIX_TIMESTAMP(NOW())
can be quite unintuitive during the last hour of daylight-saving time in the fall, as it can return a timestamp that's an hour ahead of the current time. (The docs indicate that this may be "fixed" from 4.1.3, but I have not tested.)
This is because CST-related information is lost during the conversion by NOW() from the current time to a string. When presented a date string like "2004-10-31 01:52:37" which names a time that happened twice (once during daylight-saving time, and again an hour later in standard time), it doesn't know which you intend it to be interpreted as.
The docs indicate that from 4.1.3, it uses the timezone in effect at the time of the SELECT, which implies that
FROM_UNIXTIME("2004-10-31 01:52:37")
returns a different value depending on whether you are currently under daylight-saving time or not. With 4.1.2 and before, it seems to always use standard time, and hence the one-hour "error" (which is not really an error, but damn unintuitive that UNIX_TIMESTAMP(NOW()) does not return the UNIX_TIMESTAMP for now.
Note that UNIX_TIMESTAMP() without args does return the proper unix timestamp for the current time.
If you have a table1 , and (fields date which is varchar(100)
18 rows in set (0.00 sec)you can also convert it as date type look the following example
mysql> select str_to_date(date,'%d/%m/%Y') as Mydate from table1 order by Mydate DESC;
mysql>
If you need to EXTRACT the QUARTER prior to v5.0 try CEILING(EXTRACT(MONTH FROM date)/3)
CALCULATING A DATE USING A WEEK NUMBER
If you want to calculate the date having a year, a day of the week and a weeknumber (Let's say Thursday of week number 4 in 2005), you can calculate it like this:
SELECT DATE_ADD('2005-01-04', INTERVAL ((4-1)*7+(4 - DATE_FORMAT('2005-01-04','%w'))) DAY);
In PHP it would be something like this (when weeks start on Monday):
$Days=array('xx','ma','di','wo','do','vr','za','zo');
$DayOfWeek=array_search($aDay,$Days); //get day of week (1=Monday)
$Year=2005;
$Week=4;
$query = "SELECT DATE_ADD('".$Year."-01-04', INTERVAL ((".$Week."-1)*7+(".$DayOfWeek." - DATE_FORMAT('".$Year."-01-04','%w'))) DAY)";
January 4th is chosen as a base, because it is always in week number 1. ( January 1st is not necessarely in week1! )
You can test it with this:
<?php
//connect to your database first
$Year=2005;
for ($weeknr=0; $weeknr <= 53; $weeknr++)
{
for ($day=1; $day <= 7; $day++)
{
$query = "
SELECT
DATE_ADD('".$Year."-01-04',
INTERVAL ((".$weeknr."-1)*7+
(".$day." - DATE_FORMAT('".$Year."-01-04','%w'))) DAY)
";
$result= mysql_query($query);
if ($result)
{
$row = mysql_fetch_row($result);
echo "year=$Year weekno=$weeknr day=$day : ".$row[0].'<br>';
}
else
echo 'empty result set<br>'.EOL;
}
}
?>
SELECT CONCAT(DAYOFYEAR(date1)-DAYOFYEAR(NOW()),' days ', DATE_FORMAT(ADDTIME("2000-00-00 00:00:00",SEC_TO_TIME(TIME_TO_SEC(date1)-TIME_TO_SEC(NOW()))),'%k hours and %i minutes')) AS time FROM time_table;
There doesn't appear to be an official way of selecting * from a table where eg 'date is january 2005'. So far i've found 8 different ways!!
1. where date like '2005-01-%'
2. where DATE_FORMAT(date,'%Y-%m')='2005-01'
3. where EXTRACT(YEAR_MONTH FROM date)='200501'
4. where YEAR(date)='2005' and MONTH(date)='1'
5. where substring(date,1,7)='2005-01'
6. where date between '2005-01-01' and '2005-01-31'
7. where date >= '2005-01-01' and date <= '2005-01-31'
8. where date IN('2005-01-01', '2005-01-02', '2005-01-03', '2005-01-04', '2005-01-05', '2005-01-06', '2005-01-07', '2005-01-08', '2005-01-09', '2005-01-10', '2005-01-11', '2005-01-12', '2005-01-13', '2005-01-14', '2005-01-15', '2005-01-16', '2005-01-17', '2005-01-18', '2005-01-19', '2005-01-20', '2005-01-21', '2005-01-22', '2005-01-23', '2005-01-24', '2005-01-25', '2005-01-26', '2005-01-27', '2005-01-28', '2005-01-29', '2005-01-30', '2005-01-31')
I needed a query that would delete all rows that were created over an hour ago. Here's what I used:
To insert the row:
INSERT INTO `table_name` ( `time_col`) VALUES (NOW());
To delete the rows created over an hour ago:
DELETE FROM `table_name` WHERE `time_col` < ADDDATE(NOW(), INTERVAL -1HOUR);
To take Cherice Scharf's vb example one step further, here's the conversion from vb's now format of 'MM/DD/YY HH:MM:SS PM' to 'YYYY-MM-DD HH:MM:SS' for easy insertion to the datetime field:
Function ConvertInputDateTime(varDateTime)
If (Len(Trim(varDateTime)) > 0) Then
DateTimeArray=Split(CStr(varDateTime)," ")
varDate = DateTimeArray(0)
varTime = DateTimeArray(1)
varAMPM = DateTimeArray(2)
If (Len(Trim(varDate)) > 0) Then
DateArray=Split(CStr(varDate),"/")
IF Len(Trim(DateArray(0))) < 2 Then
DateArray(0) = "0" & DateArray(0)
End If
If Len(Trim(DateArray(1))) < 2 Then
DateArray(1) = "0" & DateArray(1)
End If
If Len(Trim(DateArray(2))) < 4 Then
DateArray(2) = "20" & DateArray(2)
End If
varDate = DateArray(2) & "-" & DateArray(0) & "-" & DateArray(1)
End If
If (Len(Trim(varDate)) > 0) Then
TimeArray=Split(CStr(varTime),":")
If Trim(varAMPM) = "PM" Then
TimeArray(0) = CStr(TimeArray(0) + 12)
End If
If Len(Trim(TimeArray(0))) < 2 Then
TimeArray(0) = "0" & TimeArray(0)
End If
varTime = TimeArray(0) & ":" & TimeArray(1) & ":" & TimeArray(2)
End If
varDateTime = varDate & " " & varTime
End If
ConvertInputDateTime = varDateTime
End Function
Thanks for the starting code Cherice!
"SELECT id, transactionid, (UNIX_TIMESTAMP(now()) - UNIX_TIMESTAMP(date)) AS date , sucessful, amount FROM Transaction where sucessful = 1"
to work out the difference between when it was placed to now.
GENERATE missing days on a table with date gaps
=====================================
If you want to bring visits per day to your site and you have a table
wich
is storing the hits, in a way similar to this...
You may want to draw a chart and retrieve all the hits per day. The
problem is that DAYS WITHOUT HITS WON'T APPEAR. And you won't be able
to
display the info of '0 hits'.
One solution to this which is easy to code and clean, is to create and
have in your database, a table named 'calendar' with all the days from
today till some years from now (let's say, till 2034). The table
should
look something like this:
Here is a piece of code which will make such table:
<?php
mysql_query("CREATE TABLE `calendar` (
`id` int(11) NOT NULL auto_increment,
`date` date NOT NULL default '0000-00-00',
PRIMARY KEY (`id`)
) TYPE=MyISAM; ");
for($i=0;$i<=(365*30);$i++)
mysql_query("INSERT INTO CALENDAR SET date=date_add(now(),INTERVAL
LAST_INSERT_ID() DAY)");
?>
Then all you have to do is perform a LEFT JOIN from this table and
you've
got every day from the period of time you specify. Even those with 0
hits
SELECT calendar.date, count(*)
FROM calendar
LEFT JOIN visits ON calendar.date=visits.date
GROUP BY calendar.date
Be carefull with the DAYOFYEAR-Function in comparisions, because you will run into a trap every 4 years, when Feburary is a day shorter...
To Posted by Erin Quick-Laughlin on March 29 2005 2:49am
The much more easier way:
date = "YYYY/MM/DD HH-SS-MM"
date = Replace(date, "/", "-")
thats it...
age from date of birth compared whith
in this function you can know the age of a person(it works for my). preg 12 is a date in the format show bellow i dont know if it is fast. if you have a recent version you can asign curtime to a variable for get more performance else use php,c++ or another to save it as:
YYYY-MM-DD example: 1997-03-31
left((curtime()-preg12),(CHAR_LENGTH(curtime()-preg12)-4))
another way is:
(TO_DAYS("a - date") - TO_DAYS("birth"))/365
you can replece the curdate for a before date changing curdate to this 20000619 NOT THIS: 2000-06-19 if you have beter way send it to my tanks bye.
To calculate week ending date given an arbitrary date, use the following (assumes Saturday is week end)
SELECT DATE_ADD('2005-05-24', INTERVAL (7 - DAYOFWEEK('2005-05-24')) DAY)
SELECT DATE_ADD(table.column, INTERVAL (7 - DAYOFWEEK(table.column)) DAY)
If U have older version of MySQL you can replace 'TIMEDIFF(time1,time2)' with
'SEC_TO_TIME( (TO_DAYS(time1)*24*3600+TIME_TO_SEC(time1)) - (TO_DAYS(time2)*24*3600+TIME_TO_SEC(time2)) )'
It is completly same. :)
I had the task to select rows of a table where the date of creation was in the future of a given date.
The problem was there was no date or timestamp-field, but two fields (int), one for month and one for year.
Since I have MySQL-Version prior to 4.1.1, where most of the nice date/time-functions have been added, I had to work out a query that builds and compares dates out of the given values.
Here it is:
SELECT *
FROM your_table
WHERE CONCAT(your_table.field_year,'-',REPEAT(0,2-LENGTH(your_table.field_month)),your_table.field_month,'-','01') >= CONCAT({MIN_YEAR},'-',REPEAT(0,2-LENGTH({MIN_MONTH})),{MIN_MONTH},'-','01')
ORDER BY your_table.field_year,
your_table.field_month;
I noticed an advantage compared to working with timestamps: You are able to work with dates before 1970.
The description of FROM_DAYS(N) - "Given a daynumber N, returns a DATE value" - uses the term "daynumber" without explaining it.
The description of TO_DAYS(date) - "Given a date date, returns a daynumber (the number of days since year 0)" - lower down the page at least tries to explain the term, but unsuccessfully.
There are two problems here. Firstly, there was no year 0 in the Gregorian calendar. Secondly, a number of days has to be counted from a day, not a year. Do they mean the beginning of the (non-existent) year, or the end of the (non-existent) year? Do non-existent years even have beginnings and ends? Someone should amend these descriptions.
Here's another query to get the number of months between two dates:
select period_diff(DATE_FORMAT(date1,'%Y%m'),DATE_FORMAT(date2,'%Y%m')) from tablexy
Note that there is currently no way to get the 'AM' or 'PM' part of a time-only value using the built-in functions. You must first convert it to a datetime and then use DATE_FORMAT('%p') or perform your own calculations in your app.
On transactional consistency...Concerning the functions which use the real current time, such as NOW(), the manual says "Functions that return the current date or time each are evaluated only once per query at the start of query execution."
Note though that this does not apply across entire transactions, as you may expect. Thus a transaction like:
START TRANSACTION;
INSERT INTO EVENTS VALUES (NOW(), 'A');
INSERT INTO EVENTS VALUES (NOW(), 'B');
COMMIT;
will result in potentially two different times being recorded for the two records.
If you need the type to be dynamically taken from a table (that is where you have "year", "day", "month" etc as a column in the table), here is the best way I could work out to do it. Expand as necessary :
SELECT set_date, unit_period, unit_multiplier, CASE WHEN unit_period = "month" THEN DATE_SUB(set_date, INTERVAL unit_multiplier MONTH) WHEN unit_period = "week" THEN DATE_SUB(set_date, INTERVAL (unit_multiplier * 7) DAY) WHEN unit_period = "year" THEN DATE_SUB(set_date, INTERVAL unit_multiplier YEAR) ELSE DATE_SUB(set_date, INTERVAL unit_multiplier DAY) END FROM dates_table;
Returns all rows from actual month to given @months. eg. if you want get all rows in:
5 months from now:
(2005-09) - 5 = (2005-04)
all rows from 2005-04-01 to 2005-04-30
2 months from now
(2005-09) - 2 = (2005-07)
all rows from 2005-07-01 to 2005-07-31
SQL variables, can be PHP variables like $months,$nextMonth,$begin,$end
set @months = 1; #change only this value(months back from actual month)
set @nextMonth = @months+1;
set @begin = FROM_DAYS(TO_DAYS(LAST_DAY( DATE_SUB(NOW(), INTERVAL @nextMonth MONTH )))+1);
set @end = FROM_DAYS(TO_DAYS(LAST_DAY( DATE_SUB(NOW(), INTERVAL @months MONTH )))+1);
SELECT cols_u_want FROM tbl_u_want
WHERE timestampCol
BETWEEN @begin AND @end
It`s my solution. If U have Your own please email me.
Sorry for my english :)
I'm not sure if this is the best way, but it works to get the date of the Monday of the week of a date. For example, if you have a datetime column called starttime in a table called test_events, you could select the distinct Mondays from your table as follows:
SELECT DISTINCT(STR_TO_DATE(CONCAT(YEARWEEK(starttime),'1'),'%x%v%w'))
FROM test_events;
Hopefully there is a better way..
I was using mysql v4 and the date was in a varchar data type, in order to change the data type in mysql v5 i use the following code:
update ssd_escondida.tactual_sag4 set ssd_escondida.tactual_sag4.Fecha=str_to_date(ssd_escondida.tactual_sag4.Fecha2,'%e/%m/%Y');
where:
ssd_escondida: database
tactual_sag4:is a table
Fecha: is a date type
Fecha2:is a varchar which contains a date, but is from 01/01/2005 to 04/01/2005 (with a zero at the begining)
why i used %e instead of %d??? the answer is very simple, there is a problem with de help about str_to_date:
%d: represents the days, but from 0 to 31 and...
%e: represents the days, but from 00 to 31.
that's the reason why we cannot use: str_to_date('00/00/0000',%d/%m/%Y), we must use str_to_date('00/00/0000','%e/%m/%Y')
Another way in order to change a string like: 00/00/0000 to a date is to use: str_to_date('00/00/0000','0%d/%m/%Y')
Simple method of converting dates from any of
MM-DD-YYYY
MM/DD/YYYY
MM.DD.YYYY
(oldDate) to YYYY-MM-DD (addDate). Load date in as text and convert in one go using:
<code>
update table set addDate = CONCAT_WS('-', RIGHT( oldDate,4), LEFT( oldDate,2), SUBSTRING( oldDate,4,2))
</code>
Caveat: make sure your text input doesn't have spaces.
In MySQL 4.0, and possibly others, UNIX_TIMESTAMP() doesn't work with dates before 1970. This query does the same, and works with any date from from Fri, 13 Dec 1901 20:45:54 to Tue, 19 Jan 2038 03:14:07. 'date' is the name of the DATETIME column you need a timestamp of.
SELECT (((TO_DAYS(date) * 86400) + TIME_TO_SEC(date)) - (TO_DAYS("1970-01-01") * 86400)) AS timestamp
If you're using PHP, note that date() accounts for DST and thus may appear to return incorrect results; also, don't forget to escape the quotes around 1970-01-01.
Keyphrases: Birthday reminder, select dates between
This might be useful. If you have a database containing 'name' and 'birthday' (as columns) then the following query will list the birthdays in the next 15 days. (16 to be more precise :-))
What I found unique about this problem is that the YEAR (of birth) will always be different and hence one cannot simply use a query like :
because it would take the year into consideration.
The correct way, I believe, to get the desired result is as follows:
The logic should be clear from the query itself. Note that in one place I use numerical addition (DAYOFMONTH(CURDATE()) + 15) while lower down I use the ADDDATE function. This distinction is important.
Would be happy if someone could refine the above method.
- Noel Athaide.
PS: Put this into a script and crontab it...and you have a simple Birthday reminder :-)
the birthday-reminder doesn't work the way it should be. I found the bug and fixed it. this is a working example:
SELECT user_birthdate,user_name,user_id , EXTRACT(MONTH FROM `user_birthdate` ) month, EXTRACT(DAY FROM `user_birthdate` ) day
FROM ".$db_prefix."users
WHERE
(
EXTRACT(MONTH FROM `user_birthdate` ) = EXTRACT(MONTH FROM CURDATE())
AND
DAYOFMONTH(`user_birthdate`) > DAYOFMONTH(CURDATE())
AND
DAYOFMONTH(`user_birthdate`) <= (DAYOFMONTH(CURDATE()) + 15)
)
OR
(
EXTRACT(MONTH FROM ADDDATE(CURDATE(), INTERVAL 15 DAY))<>EXTRACT(MONTH FROM CURDATE())
AND
EXTRACT(MONTH FROM `user_birthdate`) = EXTRACT(MONTH FROM ADDDATE(CURDATE(), INTERVAL 15 DAY))
AND
DAYOFMONTH(`user_birthdate`) <= DAYOFMONTH(ADDDATE(CURDATE(), INTERVAL 15 DAY))
)
ORDER BY month, day, user_id ASC
sorry for the strange name, but this is the way my table are named...
hope you like it
I'm using this query for a birthday-reminder:
SELECT `geb_Geboorte`
FROM `gebruikers`
WHERE
DAYOFYEAR( curdate( ) ) <= dayofyear( `geb_Geboorte` )
AND
DAYOFYEAR( curdate( ) ) +15 >= dayofyear( `geb_Geboorte` );
I change the year of birthday to the current year.
Sorry for the dutch tablenames.
It took me a bit of time to find how to select data based on time periods (such as for quarterly or yearly reports). You can use group by month(DateTypeColumn).
example- to find periodic totals:
SELECT [Year|Quarter|Month|Day](date) as Period,shipcountry,shipstate,shipcity,sum(products),sum(shipping),sum(tax)
FROM products NATURAL JOIN shipping NATURAL JOIN tax
GROUP BY Period,shipcountry,shipstate,shipcity
more here-
http://dev.mysql.com/doc/refman/5.0/en/date-and-time-functions.html
I suppose you could alter the start of quarterly periods by doing some arithmetic on the (date), but you might have to do some conversions.
Time arithmetic using CURTIME() is quite willing to type everything into integers rather than adding and subtracting seconds. For example, where log_time is a TIME column;
SELECT log_time AS Time FROM call_log
WHERE log_time >= (CURTIME( ) - 60 );
will fetch all results from the last 60 seconds. However,
SELECT log_time AS Time FROM call_log
WHERE log_time >= (CURTIME( ) - 900 );
will fetch all results from the last 9 minutes. 900 is interpreted, not as 900 seconds (15 minutes), but as 9:00. An hour is 10000 (1:00:00), not 3600 (36:00).
If you want to add seconds, use something like the following (for the last hour);
SELECT log_time AS Time FROM call_log
WHERE log_time >= (CURTIME( ) - SEC_TO_TIME(3600) );
If you have a column of date values and you want to compare the day portion of them with today's date, taking in mind shorter months which might not contain all the dates in your set (example, billing systems or anything else which needs to run on each record or recordset on a given day of the month), you can try one of these (replacing '2002-04-30' with the date field you're comparing):
SELECT DATE_FORMAT(CURDATE()-INTERVAL 1 MONTH, CONCAT('%Y-%m-',DAY('2002-04-30')))+INTERVAL 1 MONTH;
This tends to "round down" on missing days - for example for dates ending in 30, this will translate to feb 28 (in february).
In reply to "David Berry on September 17 2004 9:08pm"
Problem: To find week start and end date with user specified start of the week day and user specified date for which the week is to be found.
David's solution does not work with user specified week start and end. It only works with normal week which is 1 and 7 as start and end correspondingly.
As I needed different starting day for week than Sunday or Monday for timesheet calculations, I had to come up with working solution:
...
date_sub(t.date, interval if(dayofweek(t.date)-$weekStartingDay >= 0, dayofweek(t.date)-$weekStartingDay, dayofweek(t.date)-$weekStartingDay+7) day) week_start
...
date_sub(t.date, interval if(dayofweek(t.date)-$weekStartingDay >= 0, dayofweek(t.date)-$weekStartingDay, dayofweek(t.date)-$weekStartingDay+7) - 6 day) week_end
...
This solution works fine for me, at least at the moment till I find some bug in it :)
Use this to find the date of the last Friday. Please let me know if there is a more efficient way of doing this.
select if(DATE_FORMAT(curdate(),'%w')>4,date_sub(curdate(),INTERVAL DATE_FORMAT(curdate(),'%w')-5 DAY),date_sub(curdate(),INTERVAL DATE_FORMAT(curdate(),'%w')+2 DAY))
Just another example on how to figure out how many days are until some birthdate (in order to do a range query, or get the "next" birthday):
SELECT name, birthday,
IF(DAYOFYEAR(birthday) >= DAYOFYEAR(NOW()),
DAYOFYEAR(birthday) - DAYOFYEAR(NOW()),
DAYOFYEAR(birthday) - DAYOFYEAR(NOW()) +
DAYOFYEAR(CONCAT(YEAR(NOW()),'-12-31')))
AS distance
FROM birthdates;
The + DAYOFYEAR(CONCAT(YEAR(NOW()),'-12-31')) (which is 366 or 365, depending on whether we're in a leap year or not) takes care of the New Year's Eve wrap around.
You could add WHERE distance <= 10 or ORDER BY distance ASC LIMIT 1 at the end of the query, for example.
A simple way to get the number of month between 2 date :
SELECT PERIOD_DIFF(EXTRACT(YEAR_MONTH FROM mydate1), EXTRACT(YEAR_MONTH FROM mydate2)) AS month_interval
FROM ....
Here's what I used to get a summary of some value by day of the week:
select date_format(date, "%W") AS `Day of the week`, sum(cost)
from daily_cost
group by `Day of the week`
order by date_format(date, "%w")
Output:
To order results starting with Monday, change the "order by" expression to
order by (date_format(date, "%w") - 7) % 7
LAST_DAY() with MySQL 3.23
Need to show the 1st day of the next month? - and were happy to find LAST_DAY() and just thought about adding one single day to its result? - and then discovered that you need MySQL 4+ for that?
Use this ugly chain of functions to show the 1st day of the next month - in MySQL 3.23:
FROM_DAYS(TO_DAYS(CONCAT(SUBSTRING(PERIOD_ADD(DATE_FORMAT(mydate,"%y%m" ),1),3,4),"01")))
You could subtract one day to simulate LAST_DAY() at all.
I made a Stored Function which can covert an ISO 8601 (2006-07-05T13:30:00+02:00) date to a UNIX TIMESTAMP of the corresponding UTC or GMT datetime, so you can compare timestamps from different timezones with eachother. Hope this can help someone.
CREATE FUNCTION ISO8601TOUNIXTIMESTAMP (iso varchar(25))
RETURNS INTEGER(15)
DETERMINISTIC
BEGIN
DECLARE CONVTIME INTEGER(11);
SET CONVTIME = (SUBSTRING(iso,21,2) * 60) + SUBSTRING(iso,24,2);
IF SUBSTRING(iso,20,1) = '+' THEN
SET CONVTIME = 0 - CONVTIME;
END IF;
RETURN UNIX_TIMESTAMP(DATE_ADD(STR_TO_DATE(CONCAT(SUBSTRING(iso,1,10),' ',SUBSTRING(iso,12,8)),'%Y-%m-%d %H:%i:%s'), INTERVAL CONVTIME MINUTE));
END
To get the first day of the current month:
1 row in setSELECT ((PERIOD_ADD(EXTRACT(YEAR_MONTH FROM CURDATE()),0)*100)+1) as FirstDayOfTheMonth;
This will give you the first day of the month.
mysql> SELECT ((PERIOD_ADD(EXTRACT(YEAR_MONTH FROM CURDATE()),0)*100)+1) as FirstDayOfTheMonth;
To get the last day of the current month:
SELECT (SUBDATE(ADDDATE(CURDATE(),INTERVAL 1 MONTH),INTERVAL DAYOFMONTH(CURDATE())DAY)) AS LastDayOfTheMonth;
This will give you the first day of the month.
mysql> SELECT (SUBDATE(ADDDATE(CURDATE(),INTERVAL 1 MONTH),INTERVAL DAYOFMONTH(CURDATE())DAY)) AS LastDayOfTheMonth;
1 row in set
Hope this helps!
This function will return the difference between two dates as a string, in the format "Y year[s], M month[s], D day[s]" (pluralisation as appropriate):
It took a while to work this one out, so I hope this might save someone else the bother.
I'm not sure why Horst Schirmeier did that very complex birthdate equation. Seems to me you could just do:
SET @DOYNOW = DAYOFYEAR(CURDATE());
SELECT (DAYOFYEAR(birthdate) - @DOYNOW) AS birthdays, birthdate, @DOYNOW, CURDATE()
FROM users
WHERE birthdate IS NOT NULL;
then if birthdays == 0, it's that persons birthday, otherwise you know if the birthday is in the future by how many days, or if you missed it and how many beers you owe them...
(although the missed/negative days seems to be off)
Shouldn't that -1 be -2 ?
Am I missing something obvious?
If I do "SELECT DATEDIFF('2006-08-01', CURDATE());" I get -2 as I expect.
So, I guess the real solution is to use this:
SET @YEAR = CONCAT(EXTRACT(YEAR FROM CURDATE()),'-');
SELECT DATEDIFF(CONCAT(@YEAR, DATE_FORMAT(birthdate, '%m-%d')), CURDATE()) AS birthdays, birthdate, CURDATE()
FROM users
WHERE birthdate IS NOT NULL;
By the way, if you're using PHP or some other scripting language, you can get rid of the @YEAR stuff and just do:
DATEDIFF(DATE_FORMAT(birthdate, '".date('Y')."-%m-%d'), CURDATE()) AS birthdays
Keyphrases: Birthday reminder
This is another query for the birthday remainder :
Get the first day and/or last day of the current year.
This is the first day of the year ( simple )
SELECT MAKEDATE( EXTRACT(YEAR FROM CURDATE()),1);
This is the last day ( not you can not just replace the 1 with a 365 , some years you need a 366)
SELECT STR_TO_DATE(CONCAT(12,31,EXTRACT(YEAR FROM CURDATE())), '%m%d%Y') ;
SERIAL DATES
------------
to convert dates stored as a double (Dateserial as used by microsoft etc i.e. 38883.8941421412. The whole number is the number of days since either 31/12/1899 or 01/01/1900, the fraction being the proportion of 1 day) into a dd/mm/yyyy hh:mm format:
note - MySQL requires the date taken from 31/12/1899, and even then the addition of number of days is still out by 1 because MySQL like Excel and other programs incorrectly assumes that the year 1900 was a leap year, when it wasn't for some reason.
The SQL to get the correct date is:-
ADDDATE(ADDDATE('1899-12-31 00:00',<serial date>), INTERVAL -1 DAY)
The fraction of the time can be multiplied by the number of seconds in a day (84,600) and then added to the date as a number of seconds to get the time as well, so for a datetime the SQL is:-
ADDDATE(ADDDATE(ADDDATE('1899-12-31 00:00',<serial date>), INTERVAL -1 DAY), INTERVAL (MOD(<serial date>,1) * 86400) SECOND)
Sorry is this is a bit obvious, it just took me a while to find all this out. Hope it helps.
Note that the order of arguments in TIMEDIFF is opposite than in TIMESTAMPDIFF, so:
TIMESTAMPDIFF(SECOND,expr1,expr2) = TIME_TO_SEC(TIMEDIFF(expr2,expr1))
No ready made function is provided for validate date
This function work
(you can take what ever size you want in varchar(1-1024) )
CREATE FUNCTION IsDate (sIn varchar(1024)) RETURNS INT
BEGIN
declare tp int;
if length(date(sIn)) is not null then
set tp = 0;
else
set tp = 1;
end if;
RETURN tp;
END
If you find any bug for this please post it here as this is not complete soluction as date respond are not known
I will try to solve this
Get date for first day of current week if first day of week is monday (SWEDEN, FRANCE, etc):
MONDAY
select date_sub(curdate(),INTERVAL WEEKDAY(curdate()) -0 DAY)
TUESDAY
select date_sub(curdate(),INTERVAL WEEKDAY(curdate()) -1 DAY)
AND SO ON...
The ISO 8601 week number is defined as the number of the week containing the first Thursday.
With this definition, the ISO week number corresponds to WEEK(date, 3) .
The following returns 1 for the week between 2003-12-29 and 2004-01-04:
I created this function to calculate "working day" difference of two dates. If you have table with list of holidays you may uncomment part in this function to exclude days of holidays also.
DELIMITER $$
DROP FUNCTION IF EXISTS `workdaydiff`$$
CREATE DEFINER=`root`@`%` FUNCTION `workdaydiff`(b date, a date) RETURNS int(11)
DETERMINISTIC
COMMENT 'working day difference for 2 dates'
BEGIN
DECLARE freedays int;
SET freedays = 0;
SET @x = DATEDIFF(b, a);
IF @x<0 THEN
SET @m = a;
SET a = b;
SET b = @m;
SET @m = -1;
ELSE
SET @m = 1;
END IF;
SET @x = abs(@x) + 1;
/* days in first week */
SET @w1 = WEEKDAY(a)+1;
SET @wx1 = 8-@w1;
IF @w1>5 THEN
SET @w1 = 0;
ELSE
SET @w1 = 6-@w1;
END IF;
/* days in last week */
SET @wx2 = WEEKDAY(b)+1;
SET @w2 = @wx2;
IF @w2>5 THEN
SET @w2 = 5;
END IF;
/* summary */
SET @weeks = (@x-@wx1-@wx2)/7;
SET @noweekends = (@weeks*5)+@w1+@w2;
/* Uncoment this if you want exclude also hollidays
SELECT count(*) INTO freedays FROM holliday WHERE d_day BETWEEN a AND b AND WEEKDAY(d_day)<5;
*/
SET @result = @noweekends-freedays;
RETURN @result*@m;
END$$
DELIMITER ;
If you want to select the time difference between two datetime columns and the fields may contain datetimes that are on different days, you can use the following if statement:
SELECT IF(TIME_TO_SEC(last_date)>=TIME_TO_SEC(first_date),
TIME_TO_SEC(last_date)-TIME_TO_SEC(first_date),
86400+(TIME_TO_SEC(last_date)-TIME_TO_SEC(first_date)))
FROM table;
This will return the time between the last_date and the first date, taking into account the values where first_date and last_date are on different days.
NOTE: DateFormat cannot be used to format a TimeDiff calculation.
Example:
SELECT DATE_FORMAT(TIMEDIFF(`appointment_start`,`appointment_end`),'%H:%i:%s')) AS duration FROM appointments;
Correct Syntax:
SELECT TIMEDIFF(`appointment_start`,`appointment_end`) AS duration FROM appointments;
(Tested on MySQL 4.1.20)
My pick on birthdays remainders :
select date_format( date, "%d/%m" ), DAYOFYEAR( CURDATE( ) ), DAYOFYEAR( date )
from table
where DAYOFYEAR( date ) between DAYOFYEAR( CURDATE( ) ) - 15 and DAYOFYEAR( CURDATE( ) ) + 15
order by date_format( date, "%d/%m/%Y" )
Gabriel Reguly http://ppgr.com.br
As mentioned above STR_TO_DATE() is available as of MySQL 4.1.1.
This function can be useful if you are grouping rows by Week of Year and then want to produce a table with "Week Commencing" as the points on your X-axis.
So what do you do if you're codeshop is using pre-4.1?
Here's what I did. I have a table of events happening on a datetime. I wanted an event count by week with the date of the start of the week, assuming the week starts Monday.
I have exploited the group by function to extract the minimum datetime value which in my case is guaranteed to be at least once daily.
This will not work if your data is not being injected daily!
select
count(*) as 'count',
date_format(min(added_on), '%Y-%M-%d') as 'week commencing',
date_format(added_on, '%Y%u') as 'week'
from
system
where
added_on >= '2007-05-16'
group by
week
order by 3 desc;
Hope thats useful for someone !
Imran Chaudhry
Due to a bug in mysql versions prior to 5.0.36, there is a problem when performing multiple SEC_TO_TIME conversions and there are intermediate null values. It will turn the results after the first null into null values.
For example: if you have a table (date_diff) as follows:
and you run a query:
select sec_to_time(time_to_sec(time1) - time_to_sec(time2)) as diff from date_diff;
You will see results as so:
And a query excluding id 1 will result in:
A workaround would be to use a case statement:
select case when isnull(time_to_sec(time1) - time_to_sec(time2)) then null else sec_to_time(time_to_sec(time1) - time_to_sec(time2)) end as diff from date_diff;
Or, upgrade to a mysql version including this bug fix (#25643).
To display the date of the monday preceding a given day, Bryan Donovan suggested the following:
> SELECT DISTINCT(STR_TO_DATE(CONCAT(YEARWEEK(starttime),'1'),'%x%v%w'))
> FROM test_events;
In fact, you need to be consistent in the type of weeks you use. The above would tell you that the Monday July 16 2007 is part of the week starting... Monday July 9 2007 !
This comes from week definition ambiguities (see WEEK() above). To prevent this, specify the mode on YEARWEEK to be Monday-based : pay attention to the extra parameter to the function YEARWEEK) below
One would expect that default_week_format has the same effect on WEEKDAY() than it has on WEEK() and that setting this variable to 1 or 3 would suffice. No, as of Mysql 5.0.26 it seems to have no effect:
SET default_week_format=1;
SELECT STR_TO_DATE(CONCAT(YEARWEEK('2007-07-16'),'1'),'%x%v%w')
ANNIVERSARIES ARE TRICKY!
-------------------------
For versions of MySQL previous to 4.1 it is quite difficult to determine if a date field's anniversary date falls within a specified date range. Day-of-year calculations fail because of leap years and the possibility that the date range you have specified spans a year boundary. Here is what I have come up with. Hopefully it can save someone the headache and Google Fever I had to go through to come up with it.
** SOME SELECT STATEMENT ...**
WHERE
((month(Date) BETWEEN month('[MyStartDate]') AND month('[MyEndDate]')
AND
month('[MyStartDate]') <= month('[MyEndDate]')
AND
(dayofmonth(Date) >= dayofmonth('[MyStartDate]') AND month(Date)=month('[MyStartDate]')
OR
dayofmonth(Date) <= dayofmonth('[MyEndDate]') AND month(Date)=month('[MyEndDate]')
OR
month(date) > month('[MyStartDate]') AND month(date) < month('[MyEndDate]')))
OR
(
month('[MyStartDate]') > month('[MyEndDate]')
AND
(dayofmonth(Date) >= dayofmonth('[MyStartDate]') AND month(Date)=month('[MyStartDate]')
OR
dayofmonth(Date) <= dayofmonth('[MyEndDate]') AND month(Date)=month('[MyEndDate]')
OR
month(Date) > month('[MyStartDate]')
OR month(Date) < month('[MyEndDate]')
)))
I was looking for a solution where I could return the number of days, hours, Minutes and seconds between two entries in a table.
DATE_DIFF is not running on my mysql server as my provider uses mysql version 4.0.25
Solution was to use to days and std time functions to calculate the difference in one call.
The fields stored in the table(report_table) are
time(00:00:00),
date(0000-00-00) and record(enum) which tells the app the type of log stored. EG start or end of a report.
SELECT
(TO_DAYS( `end`.`date` ) - TO_DAYS( `start`.`date` ))
-
( second( `end`.`time` ) + (minute( `end`.`time` )*60) + (hour( `end`.`time` )*3600)
<
second( `start`.`time` ) + (minute( `start`.`time` )*60) + (hour( `start`.`time` )*3600))
AS `days` ,
SEC_TO_TIME(
(second( `end`.`time` ) + (minute( `end`.`time` )*60) + (hour( `end`.`time` )*3600) )
-
(second( `start`.`time` ) + (minute( `start`.`time` )*60) + (hour( `start`.`time` )*3600) )
) AS `hms`,
`start`.`time` as `start`,
`end`.`time` as `end`
FROM `report_table` AS `start` , `report_table` AS `end`
AND `start`.`record` = 'Report Begin'
AND `end`.`record` = 'Report End'
LIMIT 1
If there is no end of report then it will not return a result, as you would expect.
Birthday reminder
4 rows in set (0.00 sec)The next birthday (including today!) is when the person is 1 year older than he/she was yesterday. So I use
mysql> select name,birthday,adddate(birthday,interval timestampdiff(year,adddate(birthday,interval 1 day),current_date)+1 year) as next_bd from person order by next_bd;
mysql> select name,birthday,adddate(birthday,interval timestampdiff(year,adddate(birthday,interval 1 day),'2008-10-12')+1 year) as next_bd from person order by next_bd;
4 rows in set (0.00 sec)
As you can see, this is also working for leap years.
BTW: Is "2008-02-29" plus 1 year" really "2009-02-28"? ;-)
To test if a date is a valid date:
SET @testdate="2007-02-29";
SELECT IF(@testdate=DATE_ADD(DATE_ADD(@testdate,INTERVAL 1 DAY),INTERVAL -1 DAY),TRUE,FALSE);
Returns 0 (false)
SET @testdate="2008-02-29";
SELECT IF(@testdate=DATE_ADD(DATE_ADD(@testdate,INTERVAL 1 DAY),INTERVAL -1 DAY),TRUE,FALSE);
Returns 1 (true)
Finding a date before a given number of days
Often, for certain applications, we need to subtract some days from a given date to find another date. For example, in a library, we need to go 21 days behind from the current date and list the books that were taken before that date. This would be the overdue list.
Here is a simple SQL statement. This type of use is practically essential to most apps.
SELECT SUBDATE( '2007-12-12', INTERVAL 3 DAY ) ;
The line above will give the answer 2007-12-9. To explain it further, the function SUBDATE returns a date after subtracting a specified duration. In our example, the duration is 3 days. To indicate that we are dealing with DAYS, we use the term INTERVAL. So the function above can be explained as “what is the date, three days before today?”
Now if you want to find the date 20 days before TODAY or the current system date, this is what you should do:
SELECT SUBDATE( CURRENT_DATE, INTERVAL 20 DAY )
In the statement above, we are using one of the MySQL constants that hold the current date on the server. We count 20 days back and get the answer as a result.
Happy coding.
Khalid (itsols)
Important: It should be known that MySQL >= 5.0.42 silently changes the behavior of comparing a DATE column to NOW().
See: http://bugs.mysql.com/bug.php?id=28929
This breaks many things since now queries using WHERE datecol = NOW() will return NULL where previously it would return results.
Use CURDATE() instead. I'm having to go back through years of code to fix this.
refering to the document section telling about intervals in date_add / date_sub functions describing example :
SELECT DATE_ADD('1999-01-01', INTERVAL 6/4 HOUR_MINUTE);
One can avoid falling into trap simply enclosing interval 6/4 into quotation marks so the query will be look like this:
SELECT DATE_ADD('1999-01-01', INTERVAL '6/4' HOUR_MINUTE);
This case the interval will be considered as regular string and no calculation will be performed before passing as argument
Earlier I used timediff in where clause worked perfectly but don't know why it is not working now especially after cpu usage exceeds in *in two different shared hosting*
query like
select * from table where timediff(sysdate(),datetimecolumn)<25
this gets rows of last 24 hours.
IF you need to run a monthly report from the 1st of each month with the previous month date, you could use the case statement below.
SELECT CASE
WHEN MONTH(CURDATE()) = 01
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Dec */
WHEN MONTH(CURDATE()) = 02
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Jan */
WHEN MONTH(CURDATE()) = 03 AND (YEAR(CURDATE())%4 = 0)
THEN SUBDATE(CURDATE(), INTERVAL 29 DAY) /* Feb Leap Year */
WHEN MONTH(CURDATE()) = 03 AND (YEAR(CURDATE())%4 != 0)
THEN SUBDATE(CURDATE(), INTERVAL 28 DAY) /* Feb */
WHEN MONTH(CURDATE()) = 04
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Mar */
WHEN MONTH(CURDATE()) = 05
THEN SUBDATE(CURDATE(), INTERVAL 30 DAY) /* Apr */
WHEN MONTH(CURDATE()) = 06
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* May */
WHEN MONTH(CURDATE()) = 07
THEN SUBDATE(CURDATE(), INTERVAL 30 DAY) /* Jun */
WHEN MONTH(CURDATE()) = 08
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Jul */
WHEN MONTH(CURDATE()) = 09
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Aug */
WHEN MONTH(CURDATE()) = 10
THEN SUBDATE(CURDATE(), INTERVAL 30 DAY) /* Sep */
WHEN MONTH(CURDATE()) = 11
THEN SUBDATE(CURDATE(), INTERVAL 31 DAY) /* Oct */
WHEN MONTH(CURDATE()) = 12
THEN SUBDATE(CURDATE(), INTERVAL 30 DAY) /* Nov */
ELSE SUBDATE(CURDATE(), INTERVAL 30 DAY) /* Defaults to 30 days */
END
Should return 'YYYY-MM-DD' from day and interval you run it on.
Example:
if the date is Jan 1st 2008 the case will return '2007-12-01'
Added this to get the 1st of the month when you run from any day of the month
SELECT CASE
WHEN MONTH(CURDATE()) = 01
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Dec */
WHEN MONTH(CURDATE()) = 02
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Jan */
WHEN MONTH(CURDATE()) = 03 AND (YEAR(CURDATE())%4 = 0)
THEN SUBDATE(CURDATE(), INTERVAL (29 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Feb Leap Year */
WHEN MONTH(CURDATE()) = 03 AND (YEAR(CURDATE())%4 != 0)
THEN SUBDATE(CURDATE(), INTERVAL (28 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Feb */
WHEN MONTH(CURDATE()) = 04
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Mar */
WHEN MONTH(CURDATE()) = 05
THEN SUBDATE(CURDATE(), INTERVAL (30 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Apr */
WHEN MONTH(CURDATE()) = 06
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* May */
WHEN MONTH(CURDATE()) = 07
THEN SUBDATE(CURDATE(), INTERVAL (30 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Jun */
WHEN MONTH(CURDATE()) = 08
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Jul */
WHEN MONTH(CURDATE()) = 09
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Aug */
WHEN MONTH(CURDATE()) = 10
THEN SUBDATE(CURDATE(), INTERVAL (30 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Sep */
WHEN MONTH(CURDATE()) = 11
THEN SUBDATE(CURDATE(), INTERVAL (31 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Oct */
WHEN MONTH(CURDATE()) = 12
THEN SUBDATE(CURDATE(), INTERVAL (30 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Nov */
ELSE SUBDATE(CURDATE(), INTERVAL (30 - (DAYOFMONTH(CURDATE()) +1 )) DAY) /* Defaults to 30 days */
END
Titel: Urlaubstage im laufenden Kalenderjahr anhand eines Arbeitstagemodells berechnen
Variablen $workable[First-Seventh] bool 1=Arbeitstag, 0=Kein Arbeitstag
$query ="
SELECT
SUM(effectiveworkdays(vrs.confirmed_from, vrs.confirmed_to, $workableFirst, $workableSecond, $workableThird, $workableFourth, $workableFifth, $workableSixth, $workableSeventh)) AS sum
FROM app_vacation_responses vrs
LEFT JOIN app_vacation_requests vrq ON vrs.request_id = vrq.vacation_id
WHERE vrq.requested_by = ". $employee_id ."
AND vrs.confirmed_from >= '". date('Y') ."-01-01'
AND vrs.confirmed_to <= '". date('Y') ."-12-31'
AND vrs.state = 1
group by vrq.requested_by
";
DELIMITER $$
DROP FUNCTION IF EXISTS `effectiveworkdays`$$
CREATE DEFINER=`myUserName`@`myHost` FUNCTION `effectiveworkdays`(STARTDATE date, ENDDATE date, WORKABLE1 integer, WORKABLE2 integer, WORKABLE3 integer, WORKABLE4 integer, WORKABLE5 integer, WORKABLE6 integer, WORKABLE7 integer) RETURNS int(11)
DETERMINISTIC
COMMENT 'effective working day for 2 dates'
BEGIN
DECLARE DAYCOUNT int;
DECLARE HOLIDAYCOUNT, HOLIDAYS int;
DECLARE STARTDAYS int;
DECLARE ENDDAYS int;
SET DAYCOUNT = 0;
SET HOLIDAYCOUNT = 0;
SET HOLIDAYS = 0;
SET STARTDAYS = TO_DAYS(STARTDATE) - 1 ;
SET ENDDAYS = TO_DAYS(ENDDATE);
IF (STARTDAYS <= ENDDAYS) THEN
WHILE (STARTDAYS <= ENDDAYS) DO
SET HOLIDAYCOUNT = 0;
IF(WORKABLE1=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=0) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE2=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=1) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE3=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=2) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE4=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=3) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE5=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=4) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE6=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=5) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
IF(WORKABLE7=1 AND WEEKDAY(FROM_DAYS(STARTDAYS))=6) THEN
SET DAYCOUNT = DAYCOUNT + 1;
SELECT count(*) INTO HOLIDAYCOUNT FROM prop_holidays WHERE d_date = FROM_DAYS(STARTDAYS);
END IF;
SET STARTDAYS = STARTDAYS + 1;
SET HOLIDAYS = HOLIDAYS + HOLIDAYCOUNT;
END WHILE;
END IF;
IF ((STARTDAYS = ENDDAYS) AND (DAYCOUNT = 0)) THEN
SET DAYCOUNT = 1;
END IF;
RETURN DAYCOUNT- HOLIDAYS;
END$$
DELIMITER ;
CREATE TABLE IF NOT EXISTS `prop_holidays` (
`holiday_id` int(11) NOT NULL auto_increment,
`name` varchar(50) NOT NULL,
`d_date` date NOT NULL,
`d_type` varchar(50) default NULL,
`d_subtype` varchar(50) default NULL,
PRIMARY KEY (`holiday_id`)
) ENGINE=MyISAM;
INSERT INTO `prop_holidays` (`holiday_id`, `name`, `d_date`, `d_type`, `d_subtype`) VALUES
(35, 'newYearsDay', '2008-01-01', 'Germany', 'BadenWuerttemberg'),
(36, 'epiphany', '2008-01-06', 'Germany', 'BadenWuerttemberg'),
(37, 'goodFriday', '2008-03-21', 'Germany', 'BadenWuerttemberg'),
(38, 'easterMonday', '2008-03-24', 'Germany', 'BadenWuerttemberg'),
(39, 'dayOfWork', '2008-05-01', 'Germany', 'BadenWuerttemberg'),
(40, 'ascensionDay', '2008-05-12', 'Germany', 'BadenWuerttemberg'),
(41, 'whitMonday', '2008-05-22', 'Germany', 'BadenWuerttemberg'),
(42, 'corpusChristi', '2008-10-03', 'Germany', 'BadenWuerttemberg'),
(43, 'germanUnificationDay', '2008-11-01', 'Germany', 'BadenWuerttemberg'),
(44, 'allSaintsDay', '2008-12-25', 'Germany', 'BadenWuerttemberg'),
(45, 'xmasDay', '2008-12-26', 'Germany', 'BadenWuerttemberg');
EXAMPLE FOR SYMFONY USERS
class VacationResponse extends BaseVacationResponse
{
public function getThisYearsLeaveDaysPaidByUserSum($employee_id){
$c = new Criteria();
$c->add(EmployeePeer::EMPLOYEE_ID, $this->getRequestParameter("id"));
$tmp = EmployeePeer::doSelect($c);
$employee = $tmp[0];
$schedule = $employee->getEmploymentContract()->getWorkSchedule();
$workableFirst = $schedule->getWorkableFirst() ==1?1:0;
$workableSecond = $schedule->getWorkableSecond() ==1?1:0;
$workableThird = $schedule->getWorkableThird() ==1?1:0;
$workableFourth = $schedule->getWorkableFourth() ==1?1:0;
$workableFifth = $schedule->getWorkableFifth() ==1?1:0;
$workableSixth = $schedule->getWorkableSixth() ==1?1:0;
$workableSeventh = $schedule->getWorkableSeventh()==1?1:0;
$query ="
SELECT
sum(effectiveworkdays2(vrs.confirmed_from, vrs.confirmed_to, $workableFirst, $workableSecond, $workableThird, $workableFourth, $workableFifth, $workableSixth, $workableSeventh)) AS sum
FROM app_vacation_responses vrs
LEFT JOIN app_vacation_requests vrq ON vrs.request_id = vrq.vacation_id
WHERE vrq.requested_by = ". $employee_id ."
AND vrs.confirmed_from >= '". date('Y') ."-01-01'
AND vrs.confirmed_to <= '". date('Y') ."-12-31'
AND vrs.state = 1
group by vrq.requested_by
";
$connection = Propel::getConnection();
$statement = $connection->prepareStatement($query);
$resultset = $statement->executeQuery();
$results = null;
foreach($resultset as $result){
if($result["sum"] < 0)
$results = 0;
else
$results = $result["sum"];
}
return $results;
}
}
If you want to find out the difference between date column and integer column you can do like the following:
select DATE_ADD(<col_name_DATE>,INTERVAL -<col_name_INTEGER> UNIT) from <table_name>
col_name_DATE : Should be DATE / DATETIME data type
col_name_INTEGER : Should be INTEGER data Type
UNIT : can be MINUTE,MONTH,....
For MySQL 4.1 you can use this query to select the month-difference between two dates, which also takes into account the amount of days of the starting month and ending month.
1. The first part is the period_diff function to get a total amount of months between two dates. Then 1 month is subtracted (because of the next two parts).
2. The second part is to calculate the part of the starting-month (results in 1 month for dates starting on the first of the month, like 01-01-2008)
3. The third part is to calculate the part of the ending-month (results in 0 for dates starting on the first of the month, like 01-02-2008)
PERIOD_DIFF(DATE_FORMAT(`end_date`,'%Y%m'),DATE_FORMAT(`start_date`,'%Y%m'))
-1
A safe and simple way to calculate the age of someone/something:
CREATE FUNCTION age (_d DATETIME) RETURNS INTEGER
COMMENT 'Given birthdate, returns current age'
RETURN YEAR(NOW()) - YEAR(_d) - IF(DATE_FORMAT(_d, '%c%d') > DATE_FORMAT(NOW(), '%c%d'), 1, 0);
I work for a publishing company and recently had a request to show the modification date/time for an article as either minutes ago, hours ago, yesterday, or date of last modification depending on how recently the article was last modified. Here's a copy of the case statement I used for this:
CASE
WHEN modified_date between date_sub(now(), INTERVAL 60 minute) and now() THEN concat(minute(TIMEDIFF(now(), modified_date)), ' minutes ago')
WHEN datediff(now(), modified_date) = 1 THEN 'Yesterday'
WHEN modified_date between date_sub(now(), INTERVAL 24 hour) and now() THEN concat(hour(TIMEDIFF(NOW(), modified_date)), ' hours ago')
ELSE date_format(modified_date, '%a, %m/%d/%y')
END
Note that the "yesterday" check occurs before the "hours" check. This is intentional so that hours will only be shown if the modification occurred during the current day.
Hope this is useful for someone else!
Here is a selection for a birthday reminder with 2 days before (INTERVAL 2 DAY):
select id, angajat_id, data_nastere from info_angajat
where DATE_ADD(date(concat(YEAR(data_nastere),"-", MONTH(NOW()), "-", DAYOFMONTH(NOW()))), INTERVAL 2 DAY)=data_nastere;
To find the start and end of a month you can use the following queries:
Last day of current month:
SELECT LAST_DAY(now());
Last day of Previous month
SELECT LAST_DAY(now() - interval 1 month );
First day of current month:
SELECT concat(date_format(LAST_DAY(now()),'%Y-%m-'),'01');
First day of previous month:
SELECT concat(date_format(LAST_DAY(now() - interval 1 month),'%Y-%m-'),'01');
Hi, here is a MySQL(5) function to validate a date, in format YYYYMMDD (example:"select isDate(20080229)"). This function include "leap year" validation.
I try to simulate "isdate()" function of Sql Server.
DELIMITER $$
CREATE FUNCTION `isDate`(s varchar(100)) RETURNS decimal(8)
BEGIN
/*valida fecha suponiendo que es ingresado como "20081228" (largo 8) */
declare tp int;
declare bisiesto int;
set s=trim(s);
/* realizamos validaciones generales */
if trim(s)=0 and length(trim(s))<>8 then
return 0; /*fecha invalida*/
end if;
if substr(s, 1,4) not between 0 and 9999 then
return 0; /*anno invalido*/
end if;
if substr(s, 5,2) not between 1 and 12 then
return 0; /*mes invalido*/
end if;
/* vemos si es bisiesto el ano */
set bisiesto=0;
if substr(s, 1,4) mod 400 = 0 then set bisiesto=1;
elseif substr(s,1,4) mod 100 = 0 then set bisiesto=0;
elseif substr(s,1,4) mod 4 = 0 then set bisiesto=1;
else set bisiesto=0;
end if;
set tp=
(case when substr(s, 7,2)<=
case substr(s, 5,2)
when '01' then 31
when '02' then
case when bisiesto=1 then 29 else 28 end /*si el anno es bisiesto febrero tiene 29 dias*/
when '03' then 31
when '04' then 30
when '05' then 31
when '06' then 30
when '07' then 31
when '08' then 31
when '09' then 30
when '10' then 31
when '11' then 30
when '12' then 31
else 0 end
and substr(s, 7,2)>0
then 1 else 0 end);
return tp;
END $$
I've always find it useful to be able to find out the number of records created on a monthly basis. This SELECT statement does the job by formatting a date field using DATE_FORMAT() and group it to see data by the year and month.
5 rows in set (0.00 sec)SELECT DATE_FORMAT(creationDate, '%Y-%m') AS month, COUNT(*) AS total FROM myTable GROUP BY month ORDER BY total DESC LIMIT 5;
The ORDER BY and LIMIT is optional, to further filter the select statement.
Regards,
Alex
http://www.loveromehotel.com/
Get first day of current week. When first day is a Sunday:
select date_sub(curdate(), interval dayofweek(curdate()) -1 day)
Joao
I found function str_to_date() very useful when having "human readable" date formats and you want to use the ORDER BY clause to sort the table by those fields:
Supposed we have a fields 'published_date' like this:
SELECT [,] published_date [,]
Now we try to ORDER BY published_date DESC, resulting in:
SELECT [,] published_date [,] ORDER BY published_date DESC []
As you can see the set is not well sorted , So simply use the str_to_date fun with the syntax:
SELECT [,] str_to_date(published_date,'%a, %d %b %Y %H:%i:%s') as my_published_date [,] ORDER BY my_published_date DESC []
So we'll have:
and the set is now sorted well.
This will give week days (everything minus weekends) between 2 dates :
SELECT
(floor( datediff( '2009-01-11', '2009-01-01' ) /7 ) *5) +
CASE dayofweek('2009-01-01')
WHEN 1 THEN mod(datediff( '2009-01-11', '2009-01-01' ) , 7) - 2
WHEN 7 THEN mod(datediff( '2009-01-11', '2009-01-01' ) , 7) - 1
ELSE
LEAST(7-dayofweek( '2009-01-01' ), mod(datediff( '2009-01-11', '2009-01-01' ) , 7))
END;
Another way to find the last day of a month (without LAST_DAY), given a date within that month:
select date_sub(concat(date_format(date_add( curdate(), interval 1 month), '%Y-%m'), '-01'), INTERVAL 1 DAY) ;
or for a specific day:
select date_sub(concat(date_format(date_add( '2008-02-18', interval 1 month), '%Y-%m'), '-01'), INTERVAL 1 DAY) ;
walks to the first of the following month, then subtracts 1 day
To find future date in X business days, took me a while but here it is without using store procedures, instead I compute the number of weekends between the initial date and date + X days, adjust for the weekend days. Its implemented as a derived table to easy joins with real tables.
<code>
/* The initial date from when to start counting */
SET @start := NOW();
/* Number of business days */
SET @days := 4;
/* The query */
SELECT calendar.`Result`
FROM (
/* If initial date is on a weekend, adjust to first business day */
SELECT @start := @start + INTERVAL CASE WHEN DAYOFWEEK(@start) = 7 THEN 2 WHEN DAYOFWEEK(@start) = 1 THEN 1 ELSE 0 END DAY `First`,
@days `Days`,
/* Number of estimated business weeks */
@weekends := DATEDIFF(@start + INTERVAL @days DAY, @start) DIV 5 `Weekends`,
/* Estimated target date based number of weekends */
@guess := @start + INTERVAL @days + 2*@weekends DAY `Guess`,
/* Adjust result date if it falls on a weekend */
IF (DAYOFWEEK(@guess) = 1, @guess + INTERVAL 1 DAY, IF (DAYOFWEEK(@guess) = 7, @guess + INTERVAL + 2 DAY, @guess)) `Result`
) calendar;
</code>
To expand a bit on the note by Jeffrey Friedl on October 31 2004 9:05am:
The manual states that FROM_UNIXTIME(UNIX_TIMESTAMP(...)) doesn't map back to the same formatted date. What also should be stated is that the reverse is not true either.
UNIX_TIMESTAMP(ts) where ts is a TIMESTAMP column returns the unix timestamp stored in it without conversion to/from a formatted date string. That avoids trouble with timezones and DST overlaps etc.
However, when the column ts is set through FROM_UNIXTIME(n), it (apparently) formats the unix timestamp as a string which is then parsed back to a timestamp again. The formatting and the parsing is done with the same time zone, so the timezone offsets generally cancel themselves out. The exception is if the timezone uses DST and the timestamp is in the overlapping hour in the fall when going from summer time to normal time.
E.g. if the active time zone on the connection is Central European Time, which uses DST, then setting 1130630400 (Sun 30 Oct 2005 2:00:00 CEST) through
INSERT INTO foo SET ts = FROM_UNIXTIME(1130630400)
actually sets the ts column to 1130634000 (Sun 30 Oct 2005 2:00:00 CET), i.e one hour later.
The only way around that problem is apparently to ensure that the time zone used on the connection is one which doesn't use DST. E.g. UTC is a reasonable choice, which can be set on the connection through "SET time_zone = '+00:00'".
I implemented a well known algorithm from an English standards organisation (I've forgotten exactly who).
for the calculate easter sunday i used following function:
DELIMITER $$
USE `pczeitdb`$$
DROP FUNCTION IF EXISTS `fneastern`$$
CREATE DEFINER=`wkroot`@`%` FUNCTION `fneastern`(iYear INT) RETURNS DATE
DETERMINISTIC
BEGIN
SET @iD=0,@iE=0,@iQ=0,@iMonth=0,@iDay=0;
SET @iD = 255 - 11 * (iYear % 19);
SET @iD = IF (@iD > 50,(@iD-21) % 30 + 21,@iD);
SET @iD = @iD - IF(@iD > 48, 1 ,0);
SET @iE = (iYear + FLOOR(iYear/4) + @iD + 1) % 7;
SET @iQ = @iD + 7 - @iE;
IF @iQ < 32 THEN
SET @iMonth = 3;
SET @iDay = @iQ;
ELSE
SET @iMonth = 4;
SET @iDay = @iQ - 31;
END IF;
RETURN STR_TO_DATE(CONCAT(iYear,'-',@iMonth,'-',@iDay),'%Y-%m-%d');
END$$
DELIMITER ;
Benjamin Zagel's posting on getting the last day of the month needs tweaking: it incorrectly told me that the last day of the month was 28th of March. This is easily remedied - simply swap the order ie. add Month First, THEN subtract a day:
ie:
SELECT DATE_FORMAT('2009-03-16' ,'%Y-%m-01') as First, (DATE_FORMAT('2009-03-16' ,'%Y-%m-01') + INTERVAL 1 MONTH) - INTERVAL 1 DAY AS Last;
(Date functions are not commutative).
I didn't find a format variable to output the ISO timezone offset "+/-HHMM", as required for RSS, SMTP or HTTP headers, etc.
The following will output the proper full-hour offset from UTC:
SELECT TIME_FORMAT( NOW() - UTC_TIMESTAMP(), '%H%i' ) AS tz_offset;
This is a SQL statement to list all the people whose birthday is coming up in the next couple of weeks, paying attention to year's end:
SET @YEAR = EXTRACT(YEAR FROM CURDATE());
SELECT name FROM mytable WHERE DATEDIFF(DATE_FORMAT(birthdate,CONCAT(@YEAR,"-%m-%d")),CURDATE()) BETWEEN 0 AND 15 OR DATEDIFF(DATE_FORMAT(birthdate,CONCAT(@YEAR + 1,"-%m-%d")),CURDATE()) BETWEEN 0 AND 15;
Much appreciation to Steven Copley's post concerning weekdays [since that is what I was looking for] but I think he used the dayofweek() function where he meant to use the weekday() function in the LEAST() clause. i.e.
This will give week days (everything minus weekends) between 2 dates :
SELECT
(floor( datediff( '2009-01-11', '2009-01-01' ) /7 ) *5) +
CASE dayofweek('2009-01-01')
WHEN 1 THEN mod(datediff( '2009-01-11', '2009-01-01' ) , 7) - 2
WHEN 7 THEN mod(datediff( '2009-01-11', '2009-01-01' ) , 7) - 1
ELSE
LEAST(7-weekday( '2009-01-01' ), mod(datediff( '2009-01-11', '2009-01-01' ) , 7))
END;
I discussed the topic of age calculation two weeks before on my blog: http://www.xarg.org/2009/12/age-calculation-with-mysql/
I found a very smart solution to calculate the age from a DATE value:
CREATE FUNCTION getage(BDAY DATE)
RETURNS TINYINT UNSIGNED
RETURN YEAR(FROM_DAYS(DATEDIFF(NOW(), BDAY)))
To calculate someones next birthday, I wrote a similar function:
CREATE DFUNCTION nextbday(bday DATE)
RETURNS DATE
RETURN DATE_ADD(bday, INTERVAL YEAR(FROM_DAYS(DATEDIFF(NOW(), bday) - 1)) + 1 YEAR)
I personally got stuck, trying to feed VBScript dates back into MySQL; as the ODBC Driver converts the MySQL dates to VBScript's version automatically.
This is a one-liner solution for everyone using VBScript (ASP), that needs to feed a VB date into MySQL.
Input: REQmod in any date format that VBScript understands (1/1/1970 12:00:01 AM)
REQmod = year(REQmod) & "-" & right("0" & month(REQmod),2) & "-" & right("0" & day(REQmod),2) & " " & right("0" & Hour(REQmod),2) & ":" & right("0" & Minute(REQmod),2) & ":" & right("0" & Second(REQmod),2)
Output: REQmod will be strictly in MySQL Format (1970-01-01 00:00:01)
Add your own comment.