Type | Storage(Bytes) | Minimum Value | Maximum Value | 是否跟时区相关 | 是否有默认行为 |
int | 4 | -2147483648 | 2147483647 | 否 | 否 |
timestamp | 4 | 1970-01-01 00:00:01(UTC) | 2038-01-19 03:14:07(UTC) | 是 | 是 |
datetime | 8 | 1000-01-01 00:00:00 | 9999-12-31 23:59:59 | 否 | 否 |
#验证了TIMESTAMP类型采用INT存储,具体差8小时原因,请查看1:时区部分
mysql> SELECT FROM_UNIXTIME(0);
+---------------------+
| FROM_UNIXTIME(0) |
+---------------------+
| 1970-01-01 08:00:00 |
+---------------------+
1 row in set (0.00 sec)
mysql> SELECT FROM_UNIXTIME(2147483647);
+---------------------------+
| FROM_UNIXTIME(2147483647) |
+---------------------------+
| 2038-01-19 11:14:07 |
+---------------------------+
1 row in set (0.00 sec)
mysql> #执行SQL
mysql> CREATE TABLE tab(
-> id BIGINT unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
-> db_create_time TIMESTAMP
-> )ENGINE=INNODB DEFAULT CHARSET=UTF8;
Query OK, 0 rows affected (0.01 sec)
mysql> #SHOW CREATE TABLE查看
mysql> #5.5版本 & 5.6版本 & 5.7版本
mysql> SHOW CREATE TABLE tab\G
*************************** 1. row ***************************
Table: tab
Create Table: CREATE TABLE `tab` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`db_create_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
1 row in set (0.00 sec)
mysql> #执行SQL
mysql> CREATE TABLE tab1(
-> id BIGINT unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
-> db_create_time TIMESTAMP,
-> db_update_time TIMESTAMP
-> )ENGINE=INNODB DEFAULT CHARSET=UTF8;
Query OK, 0 rows affected (0.01 sec)
mysql> #SHOW CREATE TABLE查看
mysql> #5.5版本 & 5.6版本 & 5.7版本
mysql> SHOW CREATE TABLE tab1 \G
*************************** 1. row ***************************
Table: tab1
Create Table: CREATE TABLE `tab1` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`db_create_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`db_update_time` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
1 row in set (0.00 sec)
mysql> #执行SQL
mysql> CREATE TABLE tab2(
-> id BIGINT unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
-> db_create_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
-> db_update_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
-> )ENGINE=INNODB DEFAULT CHARSET=UTF8;
Query OK, 0 rows affected (0.01 sec)
mysql> #SHOW CREATE TABLE查看
mysql> #5.6版本 & 5.7版本
mysql> SHOW CREATE TABLE tab2 \G
*************************** 1. row ***************************
Table: tab2
Create Table: CREATE TABLE `tab2` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`db_create_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`db_update_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
1 row in set (0.00 sec)
#5.5版本报错了(MySQL5.5版本不支持多个DEFAULT CURRENT_TIMESTAMP属性的字段)
ERROR 1293 (HY000): Incorrect table definition; there can be only one TIMESTAMP column with CURRENT_TIMESTAMP in DEFAULT or ON UPDATE clause
#5.5版本 & 5.6版本 & 5.7版本
mysql> #执行SQL
mysql> CREATE TABLE tab3(
-> id BIGINT unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
-> db_create_time TIMESTAMP NOT NULL DEFAULT '2000-01-01 00:00:00'
-> )ENGINE=INNODB DEFAULT CHARSET=UTF8;
Query OK, 0 rows affected (0.00 sec)
mysql> SHOW CREATE TABLE tab3 \G
*************************** 1. row ***************************
Table: tab3
Create Table: CREATE TABLE `tab3` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`db_create_time` timestamp NOT NULL DEFAULT '2000-01-01 00:00:00',
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
1 row in set (0.01 sec)
mysql> INSERT INTO tab3 VALUES(1,NULL);
Query OK, 1 row affected (0.00 sec)
mysql> SELECT * FROM tab3;
+----+---------------------+
| id | db_create_time |
+----+---------------------+
| 1 | 2017-06-29 22:46:53 |
+----+---------------------+
1 row in set (0.01 sec)