13.2.5 Automatic Initialization and Updating for TIMESTAMP and DATETIME (original) (raw)

13.2.5 Automatic Initialization and Updating for TIMESTAMP and DATETIME

TIMESTAMP andDATETIME columns can be automatically initialized and updated to the current date and time (that is, the current timestamp).

For any TIMESTAMP orDATETIME column in a table, you can assign the current timestamp as the default value, the auto-update value, or both:

In addition, if theexplicit_defaults_for_timestamp system variable is disabled, you can initialize or update anyTIMESTAMP (but notDATETIME) column to the current date and time by assigning it a NULL value, unless it has been defined with the NULL attribute to permit NULL values.

To specify automatic properties, use the DEFAULT CURRENT_TIMESTAMP and ON UPDATE CURRENT_TIMESTAMP clauses in column definitions. The order of the clauses does not matter. If both are present in a column definition, either can occur first. Any of the synonyms for CURRENT_TIMESTAMP have the same meaning asCURRENT_TIMESTAMP. These areCURRENT_TIMESTAMP(),NOW(),LOCALTIME,LOCALTIME(),LOCALTIMESTAMP, andLOCALTIMESTAMP().

Use of DEFAULT CURRENT_TIMESTAMP andON UPDATE CURRENT_TIMESTAMP is specific toTIMESTAMP andDATETIME. TheDEFAULT clause also can be used to specify a constant (nonautomatic) default value (for example,DEFAULT 0 or DEFAULT '2000-01-01 00:00:00').

TIMESTAMP orDATETIME column definitions can specify the current timestamp for both the default and auto-update values, for one but not the other, or for neither. Different columns can have different combinations of automatic properties. The following rules describe the possibilities:

CREATE TABLE t1 (  
  ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,  
  dt DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP  
);  
CREATE TABLE t1 (  
  ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP,  
  dt DATETIME DEFAULT CURRENT_TIMESTAMP  
);  

With a constant, the default is the given value. In this case, the column has no automatic properties at all.

CREATE TABLE t1 (  
  ts TIMESTAMP DEFAULT 0,  
  dt DATETIME DEFAULT 0  
);  
CREATE TABLE t1 (  
  ts TIMESTAMP DEFAULT 0 ON UPDATE CURRENT_TIMESTAMP,  
  dt DATETIME DEFAULT 0 ON UPDATE CURRENT_TIMESTAMP  
);  
CREATE TABLE t1 (  
  ts1 TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,     -- default 0  
  ts2 TIMESTAMP NULL ON UPDATE CURRENT_TIMESTAMP -- default NULL  
);  

DATETIME has a default ofNULL unless defined with the NOT NULL attribute, in which case the default is 0.

CREATE TABLE t1 (  
  dt1 DATETIME ON UPDATE CURRENT_TIMESTAMP,         -- default NULL  
  dt2 DATETIME NOT NULL ON UPDATE CURRENT_TIMESTAMP -- default 0  
);  

TIMESTAMP andDATETIME columns have no automatic properties unless they are specified explicitly, with this exception: If theexplicit_defaults_for_timestamp system variable is disabled, the first TIMESTAMP column has bothDEFAULT CURRENT_TIMESTAMP and ON UPDATE CURRENT_TIMESTAMP if neither is specified explicitly. To suppress automatic properties for the firstTIMESTAMP column, use one of these strategies:

Consider these table definitions:

CREATE TABLE t1 (
  ts1 TIMESTAMP DEFAULT 0,
  ts2 TIMESTAMP DEFAULT CURRENT_TIMESTAMP
                ON UPDATE CURRENT_TIMESTAMP);
CREATE TABLE t2 (
  ts1 TIMESTAMP NULL,
  ts2 TIMESTAMP DEFAULT CURRENT_TIMESTAMP
                ON UPDATE CURRENT_TIMESTAMP);
CREATE TABLE t3 (
  ts1 TIMESTAMP NULL DEFAULT 0,
  ts2 TIMESTAMP DEFAULT CURRENT_TIMESTAMP
                ON UPDATE CURRENT_TIMESTAMP);

The tables have these properties:

If a TIMESTAMP orDATETIME column definition includes an explicit fractional seconds precision value anywhere, the same value must be used throughout the column definition. This is permitted:

CREATE TABLE t1 (
  ts TIMESTAMP(6) DEFAULT CURRENT_TIMESTAMP(6) ON UPDATE CURRENT_TIMESTAMP(6)
);

This is not permitted:

CREATE TABLE t1 (
  ts TIMESTAMP(6) DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP(3)
);

TIMESTAMP Initialization and the NULL Attribute

If theexplicit_defaults_for_timestamp system variable is disabled,TIMESTAMP columns by default areNOT NULL, cannot containNULL values, and assigningNULL assigns the current timestamp. To permit a TIMESTAMP column to containNULL, explicitly declare it with theNULL attribute. In this case, the default value also becomes NULL unless overridden with a DEFAULT clause that specifies a different default value. DEFAULT NULL can be used to explicitly specify NULL as the default value. (For a TIMESTAMP column not declared with the NULL attribute,DEFAULT NULL is invalid.) If aTIMESTAMP column permitsNULL values, assigningNULL sets it to NULL, not to the current timestamp.

The following table contains severalTIMESTAMP columns that permitNULL values:

CREATE TABLE t
(
  ts1 TIMESTAMP NULL DEFAULT NULL,
  ts2 TIMESTAMP NULL DEFAULT 0,
  ts3 TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP
);

A TIMESTAMP column that permitsNULL values does not take on the current timestamp at insert time except under one of the following conditions:

In other words, a TIMESTAMP column defined to permit NULL values auto-initializes only if its definition includesDEFAULT CURRENT_TIMESTAMP:

CREATE TABLE t (ts TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP);

If the TIMESTAMP column permitsNULL values but its definition does not include DEFAULT CURRENT_TIMESTAMP, you must explicitly insert a value corresponding to the current date and time. Suppose that tables t1 andt2 have these definitions:

CREATE TABLE t1 (ts TIMESTAMP NULL DEFAULT '0000-00-00 00:00:00');
CREATE TABLE t2 (ts TIMESTAMP NULL DEFAULT NULL);

To set the TIMESTAMP column in either table to the current timestamp at insert time, explicitly assign it that value. For example:

INSERT INTO t2 VALUES (CURRENT_TIMESTAMP);
INSERT INTO t1 VALUES (NOW());

If theexplicit_defaults_for_timestamp system variable is enabled,TIMESTAMP columns permitNULL values only if declared with theNULL attribute. Also,TIMESTAMP columns do not permit assigning NULL to assign the current timestamp, whether declared with the NULL orNOT NULL attribute. To assign the current timestamp, set the column toCURRENT_TIMESTAMP or a synonym such as NOW().