TIMESTAMP Type

Overview

Accepts a datetime value consisting of year (1970-2038), month, day, hours, minutes, seconds, and microseconds.

USAGE

TIMESTAMP [(<microsecond_precision>)]

DETAILS

Data Type

Minimum Value

Maximum Value

TIMESTAMP

1970-01-01 00:00:00 (UTC)

2038-01-19 03:14:07 (UTC)

Replication

  • When replicating from MariaDB Xpand to MariaDB Xpand, use row-based replication when using fractional seconds.

  • When replicating from MariaDB Xpand to MariaDB Enterprise Server, fractional seconds cannot be replicated safely.

MySQL Compatibility

As with MySQL, Xpand will interpret input values supplied to DATE and TIME functions and convert them to a standard format. However, unpredictable results may occur if values are provided in other formats.

Xpand matches MySQL with the exception of:

  • Xpand does not support casting a TIME to a DATETIME and returns NULL.

  • Xpand does not support casting a TIME to a DATE or a DATE to a TIME.

  • When converting from a DATETIME to a DATE, Xpand will discard the the time portion. MySQL will take fractional seconds into account and round the time part.

  • Casting negative value to DATETIME will return a zero date. MySQL returns NULL.

  • When the input to LAST_DAY is a DATETIME, MySQL will round to the nearest DATE before computing LAST_DAY where Xpand does not. For example, LAST_DAY('2013-01-31 23:59:59.999999') returns '2017-01-31' on Xpand and '2017-02-01' on MySQL.

  • If an invalid format string is supplied to STR_TO_DATE, Xpand will return NULL. MySQL ignores extra characters at the end of format string.

  • The results when using EXTRACT with compound units (e.g., DAY_SECOND, DAY_MICROSECOND) may exclude some of the requested units or return incorrect results.

  • Output from datetime functions (e.g., NOW(), INTERVAL() FROM_UNIXTIME(), SUBTIME()) display microsecond precision by default.

  • UNIX_TIMESTAMP() and FROM_UNIXTIME do not support input with fractional seconds.

  • Boolean values (True, False, Null) are accepted in a DATETIME column. This matches the behavior for MySQL v5.5. MySQL v5.6 provides an error message.

  • On Xpand, specifying a zero value for day, month, or year within a date will result in a zero date ('0000-00-00'). MySQL will issue an error (if the sql_mode for NO_ZERO_IN_DATE) is set, or allow zero value for the specific portion of the date.

Replication Compatibility

MariaDB recommends using row-based replication when utilizing fractional seconds.

Fractional seconds cannot be replicated safely from Xpand to MariaDB Enterprise Server.

SYNONYMS

SCHEMA

PARAMETERS

SKYSQL

PRIVILEGES

EXAMPLES

DEFAULT CURRENT_TIMESTAMP

Similar to MariaDB Server and MySQL, Xpand supports DEFAULT CURRENT_TIMESTAMP:

CREATE TABLE timestamp_default_current_timestamp (
   id BIGINT(0) UNSIGNED AUTO_UNIQUE PRIMARY KEY,
   data varchar(100),
   ts_added TIMESTAMP(6) DEFAULT CURRENT_TIMESTAMP(6),
   ts_updated TIMESTAMP(6) DEFAULT CURRENT_TIMESTAMP(6) ON UPDATE CURRENT_TIMESTAMP(6)
);

Formats

Xpand supports multiple TIMESTAMP formats, including values with fractional second precision up to 6 digits (microseconds):

CREATE TABLE timestamp_formats_example (
  description VARCHAR(30),
  example TIMESTAMP(6)
);
-- The time zone affects the values
SET @@time_zone = '+00:00';

INSERT INTO timestamp_formats_example VALUES
  ('Date without time', '2022-12-30'),
  ('Full year', '2022-12-30 00:00:00'),
  ('Short year', '22-12-30 00:00:00.000'),
  ('Pipe delimiters', '22|2|3 22|00|00.123456'),
  ('Forward slash delimiter', '22/12/30 00/00/00.0');

SET @@time_zone = '-07:00';

INSERT INTO timestamp_formats_example VALUES
  ('Asterisk delimiter', '22*12*30 8*35*00'),
  ('Comma delimiter', '22,2,3 12,34,56.123');

When a TIMESTAMP value is selected, the DATE_FORMAT() function can be used to control the output format. By default, the value is returned in the YYYY-MM-DD HH:MM:SS.ffffff format, which is equivalent to DATE_FORMAT(<timestamp>, '%Y-%m-%d %H:%i:%S.%f'):

SET @@time_zone = '+00:00';

SELECT * FROM timestamp_formats_example;
+-------------------------+----------------------------+
| description             | example                    |
+-------------------------+----------------------------+
| Date without time       | 2022-12-30 00:00:00.000000 |
| Full year               | 2022-12-30 00:00:00.000000 |
| Short year              | 2022-12-30 00:00:00.000000 |
| Pipe delimiters         | 2022-02-03 22:00:00.123456 |
| Forward slash delimiter | 2022-12-30 00:00:00.000000 |
| Asterisk delimiter      | 2022-12-30 15:35:00.000000 |
| Comma delimiter         | 2022-02-03 19:34:56.123000 |
+-------------------------+----------------------------+

Default Microsecond Precision

The default microsecond precision when unspecified is 0:

CREATE TABLE timestamp_no_microseconds_example (
   description VARCHAR(30),
   example TIMESTAMP
);

Remove Microsecond Precision

To remove microsecond precision from a TIMESTAMP(6) column, use the DATE_FORMAT() function:

SELECT description, DATE_FORMAT(example, '%Y-%m-%d %H:%i:%S') AS example FROM timestamp_formats_example;
+-------------------------+---------------------+
| description             | example             |
+-------------------------+---------------------+
| Date without time       | 2022-12-30 00:00:00 |
| Full year               | 2022-12-30 00:00:00 |
| Short year              | 2022-12-30 00:00:00 |
| Pipe delimiters         | 2022-02-03 22:00:00 |
| Forward slash delimiter | 2022-12-30 00:00:00 |
| Asterisk delimiter      | 2022-12-30 15:35:00 |
| Comma delimiter         | 2022-02-03 19:34:56 |
+-------------------------+---------------------+

Range

Xpand does not reject out-of-range values for the TIMESTAMP data type. Out-of-range TIMESTAMP values are always accepted and replaced with "zero dates", even when sql_mode=STRICT_TRANS_TABLES is set:

CREATE TABLE timestamp_range_example (
   description VARCHAR(30),
   example TIMESTAMP(6)
);
-- The time zone affects the values
SET @@time_zone = '+00:00';

INSERT INTO timestamp_range_example VALUES
   ('Minimum timestamp', '1970-01-01 00:00:00.000001'),
   ('Maximum timestamp', '2038-01-19 03:14:07.999999'),
   ('Below minimum range', '1969-12-31 23:59:59'),
   ('Above maximum range', '2038-01-19 03:14:08');
SELECT * FROM timestamp_range_example;
+---------------------+----------------------------+
| description         | example                    |
+---------------------+----------------------------+
| Minimum timestamp   | 1970-01-01 00:00:00.000001 |
| Maximum timestamp   | 2038-01-19 03:14:07.999999 |
| Below minimum range | 0000-00-00 00:00:00.000000 |
| Above maximum range | 0000-00-00 00:00:00.000000 |
+---------------------+----------------------------+

ERROR HANDLING

FEATURE INTERACTION

RESPONSES

DIAGNOSIS

ISO 9075:2016

CHANGE HISTORY

Release Series

History

23.09

  • Present starting in MariaDB Xpand 23.09.1.

6.1

  • Present starting in MariaDB Xpand 6.1.0.

6.0

  • Present starting in MariaDB Xpand 6.0.3.

5.3

  • Present starting in MariaDB Xpand 5.3.13.

Release Series

History

6.0

  • Present starting in MariaDB Xpand 6.0.3.

5.3

  • Present starting in MariaDB Xpand 5.3.13.

Release Series

History

6.1

  • Present starting in MariaDB Xpand 6.1.0.

EXTERNAL REFERENCES