MySql Timestamp默认值限制问题
约 478 字大约 2 分钟
今天在往mysql表中新增一列timestamp时,希望设置默认值为0,结果发现居然提示失败,记录一下
问题记录
测试的mysql版本为 5.7.24
创建要给测试的表用来说明
mysql> show create table demo\G
*************************** 1. row ***************************
Table: demo
Create Table: CREATE TABLE `demo` (
`id` bigint(20) NOT NULL AUTO_INCREMENT,
`age` int(10) NOT NULL DEFAULT '0',
`name` varchar(30) NOT NULL DEFAULT '',
PRIMARY KEY (`id`),
KEY `UNI_AGE` (`age`),
KEY `name` (`name`)
) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=utf8mb4
1 row in set (0.00 sec)
我们希望在这个表里面,新增一列, 默认值为0(即对应的日期为1970-01-01 00:00:00
)
mysql> alter table demo add column test_time timestamp not null default '1970-01-01 00:00:00';
ERROR 1067 (42000): Invalid default value for 'test_time'
直接提示默认值非法,why?
官方说明: https://dev.mysql.com/doc/refman/5.7/en/datetime.html
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.
默认值有限制,要求必须是>=1970-01-01 00:00:01
且 <=2038-01-19 03:14:07
然后我们再测试一下
mysql> alter table demo add column test_time timestamp not null default '1970-01-01 00:00:01';
ERROR 1067 (42000): Invalid default value for 'test_time'
依然是失败!!! why?
注意上面说的时间是utc日期,而我们大中华是utc8
所以我们需要把时间设置为8:00:01
mysql> alter table demo add column test_time timestamp not null default '1970-01-01 08:00:01';
Query OK, 0 rows affected (0.18 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> show create table demo\G
*************************** 1. row ***************************
Table: demo
Create Table: CREATE TABLE `demo` (
`id` bigint(20) NOT NULL AUTO_INCREMENT,
`age` int(10) NOT NULL DEFAULT '0',
`name` varchar(30) NOT NULL DEFAULT '',
`test_time` timestamp NOT NULL DEFAULT '1970-01-01 08:00:01',
PRIMARY KEY (`id`),
KEY `UNI_AGE` (`age`),
KEY `name` (`name`)
) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=utf8mb4
1 row in set (0.01 sec)
Loading...