The date and time data types for representing temporal values
        are DATE,
        TIME,
        DATETIME,
        TIMESTAMP, and
        YEAR.
      
        For the DATE and
        DATETIME range descriptions,
        “supported” means that although earlier values
        might work, there is no guarantee.
      
        MySQL permits fractional seconds for
        TIME,
        DATETIME, and
        TIMESTAMP values, with up to
        microseconds (6 digits) precision. To define a column that
        includes a fractional seconds part, use the syntax
        type_name(fsp)type_name is
        TIME,
        DATETIME, or
        TIMESTAMP, and
        fsp is the fractional seconds
        precision. For example:
      
CREATE TABLE t1 (t TIME(3), dt DATETIME(6), ts TIMESTAMP(0));
        The fsp value, if given, must be in
        the range 0 to 6. A value of 0 signifies that there is no
        fractional part. If omitted, the default precision is 0. (This
        differs from the standard SQL default of 6, for compatibility
        with previous MySQL versions.)
      
        Any TIMESTAMP or
        DATETIME column in a table can
        have automatic initialization and updating properties; see
        Section 13.2.5, “Automatic Initialization and Updating for TIMESTAMP and DATETIME”.
- A date. The supported range is - '1000-01-01'to- '9999-12-31'. MySQL displays- DATEvalues in- 'format, but permits assignment of values to- YYYY-MM-DD'- DATEcolumns using either strings or numbers.
- A date and time combination. The supported range is - '1000-01-01 00:00:00.000000'to- '9999-12-31 23:59:59.499999'. MySQL displays- DATETIMEvalues in- 'format, but permits assignment of values to- YYYY-MM-DD hh:mm:ss[.- fraction]'- DATETIMEcolumns using either strings or numbers.- An optional - fspvalue in the range from 0 to 6 may be given to specify fractional seconds precision. A value of 0 signifies that there is no fractional part. If omitted, the default precision is 0.- Automatic initialization and updating to the current date and time for - DATETIMEcolumns can be specified using- DEFAULTand- ON UPDATEcolumn definition clauses, as described in Section 13.2.5, “Automatic Initialization and Updating for TIMESTAMP and DATETIME”.
- A timestamp. The range is - '1970-01-01 00:00:01.000000'UTC to- '2038-01-19 03:14:07.499999'UTC.- TIMESTAMPvalues are stored as the number of seconds since the epoch (- '1970-01-01 00:00:00'UTC). A- TIMESTAMPcannot represent the value- '1970-01-01 00:00:00'because that is equivalent to 0 seconds from the epoch and the value 0 is reserved for representing- '0000-00-00 00:00:00', the “zero”- TIMESTAMPvalue.- An optional - fspvalue in the range from 0 to 6 may be given to specify fractional seconds precision. A value of 0 signifies that there is no fractional part. If omitted, the default precision is 0.- The way the server handles - TIMESTAMPdefinitions depends on the value of the- explicit_defaults_for_timestampsystem variable (see Section 7.1.8, “Server System Variables”).- If - explicit_defaults_for_timestampis enabled, there is no automatic assignment of the- DEFAULT CURRENT_TIMESTAMPor- ON UPDATE CURRENT_TIMESTAMPattributes to any- TIMESTAMPcolumn. They must be included explicitly in the column definition. Also, any- TIMESTAMPnot explicitly declared as- NOT NULLpermits- NULLvalues.- If - explicit_defaults_for_timestampis disabled, the server handles- TIMESTAMPas follows:- Unless specified otherwise, the first - TIMESTAMPcolumn in a table is defined to be automatically set to the date and time of the most recent modification if not explicitly assigned a value. This makes- TIMESTAMPuseful for recording the timestamp of an- INSERTor- UPDATEoperation. You can also set any- TIMESTAMPcolumn to the current date and time by assigning it a- NULLvalue, unless it has been defined with the- NULLattribute to permit- NULLvalues.- Automatic initialization and updating to the current date and time can be specified using - DEFAULT CURRENT_TIMESTAMPand- ON UPDATE CURRENT_TIMESTAMPcolumn definition clauses. By default, the first- TIMESTAMPcolumn has these properties, as previously noted. However, any- TIMESTAMPcolumn in a table can be defined to have these properties.
- A time. The range is - '-838:59:59.000000'to- '838:59:59.000000'. MySQL displays- TIMEvalues in- 'format, but permits assignment of values to- hh:mm:ss[.- fraction]'- TIMEcolumns using either strings or numbers.- An optional - fspvalue in the range from 0 to 6 may be given to specify fractional seconds precision. A value of 0 signifies that there is no fractional part. If omitted, the default precision is 0.
- A year in 4-digit format. MySQL displays - YEARvalues in- YYYYformat, but permits assignment of values to- YEARcolumns using either strings or numbers. Values display as- 1901to- 2155, or- 0000.- For additional information about - YEARdisplay format and interpretation of input values, see Section 13.2.4, “The YEAR Type”.Note- As of MySQL 8.0.19, the - YEAR(4)data type with an explicit display width is deprecated; you should expect support for it to be removed in a future version of MySQL. Instead, use- YEARwithout a display width, which has the same meaning.- MySQL 8.0 does not support the 2-digit - YEAR(2)data type permitted in older versions of MySQL. For instructions on converting to 4-digit- YEAR, see 2-Digit YEAR(2) Limitations and Migrating to 4-Digit YEAR, in MySQL 5.7 Reference Manual.
        The SUM() and
        AVG() aggregate functions do not
        work with temporal values. (They convert the values to numbers,
        losing everything after the first nonnumeric character.) To work
        around this problem, convert to numeric units, perform the
        aggregate operation, and convert back to a temporal value.
        Examples:
      
SELECT SEC_TO_TIME(SUM(TIME_TO_SEC(time_col))) FROM tbl_name;
SELECT FROM_DAYS(SUM(TO_DAYS(date_col))) FROM tbl_name;