Documentation Home
MySQL 5.5 Reference Manual
Related Documentation Download this Manual Excerpts from this Manual

MySQL 5.5 Reference Manual  /  ...  /  The DATE, DATETIME, and TIMESTAMP Types

11.3.1 The DATE, DATETIME, and TIMESTAMP Types

The DATE, DATETIME, and TIMESTAMP types are related. This section describes their characteristics, how they are similar, and how they differ. MySQL recognizes DATE, DATETIME, and TIMESTAMP values in several formats, described in Section 9.1.3, “Date and Time Literals”. For the DATE and DATETIME range descriptions, supported means that although earlier values might work, there is no guarantee.

The DATE type is used for values with a date part but no time part. MySQL retrieves and displays DATE values in 'YYYY-MM-DD' format. The supported range is '1000-01-01' to '9999-12-31'.

The DATETIME type is used for values that contain both date and time parts. MySQL retrieves and displays DATETIME values in 'YYYY-MM-DD HH:MM:SS' format. The supported range is '1000-01-01 00:00:00' to '9999-12-31 23:59:59'.

The TIMESTAMP data type is used for values that contain both date and time parts. TIMESTAMP has a range of '1970-01-01 00:00:01' UTC to '2038-01-19 03:14:07' UTC.

MySQL converts TIMESTAMP values from the current time zone to UTC for storage, and back from UTC to the current time zone for retrieval. (This does not occur for other types such as DATETIME.) By default, the current time zone for each connection is the server's time. The time zone can be set on a per-connection basis. As long as the time zone setting remains constant, you get back the same value you store. If you store a TIMESTAMP value, and then change the time zone and retrieve the value, the retrieved value is different from the value you stored. This occurs because the same time zone was not used for conversion in both directions. The current time zone is available as the value of the time_zone system variable. For more information, see Section 10.6, “MySQL Server Time Zone Support”.

The TIMESTAMP data type offers automatic initialization and updating to the current date and time. For more information, see Section 11.3.5, “Automatic Initialization and Updating for TIMESTAMP”.

A DATETIME or TIMESTAMP value can include a trailing fractional seconds part in up to microseconds (6 digits) precision. Although this fractional part is recognized, it is discarded from values stored into DATETIME or TIMESTAMP columns. For information about fractional seconds support in MySQL, see Section 11.3.6, “Fractional Seconds in Time Values”.

Invalid DATE, DATETIME, or TIMESTAMP values are converted to the zero value of the appropriate type ('0000-00-00' or '0000-00-00 00:00:00').

Be aware of certain properties of date value interpretation in MySQL:

  • MySQL permits a relaxed format for values specified as strings, in which any punctuation character may be used as the delimiter between date parts or time parts. In some cases, this syntax can be deceiving. For example, a value such as '10:11:12' might look like a time value because of the : delimiter, but is interpreted as the year '2010-11-12' if used in a date context. The value '10:45:15' is converted to '0000-00-00' because '45' is not a valid month.

  • The server requires that month and day values be valid, and not merely in the range 1 to 12 and 1 to 31, respectively. With strict mode disabled, invalid dates such as '2004-04-31' are converted to '0000-00-00' and a warning is generated. With strict mode enabled, invalid dates generate an error. To permit such dates, enable ALLOW_INVALID_DATES. See Section 5.1.7, “Server SQL Modes”, for more information.

  • MySQL does not accept TIMESTAMP values that include a zero in the day or month column or values that are not a valid date. The sole exception to this rule is the special zero value '0000-00-00 00:00:00'.

  • CAST() treats a TIMESTAMP value as a string when not selecting from a table. (This is true even if you specify FROM DUAL.) See Section 12.10, “Cast Functions and Operators”.

  • Dates containing two-digit year values are ambiguous because the century is unknown. MySQL interprets two-digit year values using these rules:

    • Year values in the range 00-69 are converted to 2000-2069.

    • Year values in the range 70-99 are converted to 1970-1999.

    See also Section 11.3.8, “Two-Digit Years in Dates”.


The MySQL server can be run with the MAXDB SQL mode enabled. In this case, TIMESTAMP is identical with DATETIME. If this mode is enabled at the time that a table is created, TIMESTAMP columns are created as DATETIME columns. As a result, such columns use DATETIME display format, have the same range of values, and there is no automatic initialization or updating to the current date and time. See Section 5.1.7, “Server SQL Modes”.

Download this Manual
User Comments
  Posted by Linus Rachlis on November 12, 2009
You can automatically convert an invalid date to the valid equivalent like this:

SELECT '2008-02-31' + INTERVAL 0 DAY;
# 2008-03-02

This lets you avoid storing invalid dates without bothering the user and without having to manually program a fix into your app. I suppose in >=5.0.2, you'd have to enable ALLOW_INVALID_DATES to avoid having it converted to '0000-00-00'. This also works with DATETIMEs.
  Posted by Kadir Güngör on June 12, 2009
In addition to Linus Rachlis,
if you add 0 month to an invalid date, you could get last day of the month, for example

SELECT '2008-02-31' + INTERVAL 0 MONTH;
# 2008-02-29

It works as

SELECT LAST_DAY('2008-02-31');
# 2008-02-29
  Posted by yaswanth reddy on October 22, 2011
even we can add a trigger to check a valid date so that it atomatically changes to correct date
  Posted by DBA Lead on December 13, 2011
A possible problem that can happen with date_format and ORDER/GROUP BY is explained at
  Posted by Brian Layman on April 2, 2014
Please note that year restriction of 1000-9999 appears to be in place in versions 5.0.2+. The wording of this documentation doesn't make it clear whether or not this year restriction remained in place.

The ODBC driver at least seems to enforce the restriction by bombing out when exporting a year such as 193/08/17.

The 5.0.2 change appears to add an additional validity check and not replace any existing restrictions.
  Posted by heidi heidi on March 3, 2015
STEP 1: Download the db_school database then import the database on your MySQL server.

You must have the following tables:

STEP 2: Examine each table structure.

STEP 3: Create a trigger that will automatically generate the
id number (studid) of each new student. The ID number
is generated as describe below.

Examine the sample ID Number : 00015010

0001 = Number of records (since this is the first record)
5 = Month (numeric)
0 = Current Selected Semester
10 = Current Selected School Year

Assume: The tbl_students has 200 records then the next id number should be,
Note: ID number should be eight characters only.

STEP 4: To check if your trigger works..try execute the following comand.

One at a time..please...

1. INSERT INTO tbl_students VALUES('123','Taborda','Rogie','BSIT',now());
2. INSERT INTO tbl_students VALUES('341','Viloria','Angela','BSIT',now());
3. INSERT INTO tbl_students VALUES('512','Astrero','Jessa','BSIT',now());
Sign Up Login You must be logged in to post a comment.