[MySQL优化案例]系列 -- 用TIMESTAMP类型取代INT和DATETIME
引言:在以前,我总是习惯用 INT UNSIGNED 来存储一个转换成Unix时间戳的时间值,认为这样做从索引,比较等角度来讲,都会比较高效。现在我们来对比下 TIMESTAMP 和 INT UNSIGNED 以及 DATETIME 这3种类型到底谁更好。
1. 准备
创建一个测试表:
mysql> CREATE TABLE `t` ( `d1` int(10) unsigned NOT NULL default '0', `d2` timestamp NOT NULL default CURRENT_TIMESTAMP, `d3` datetime NOT NULL, KEY `d2` (`d2`), KEY `d1` (`d1`), KEY `d3` (`d3`) );
然后创建一个存储过程填充数据:
mysql> DELIMITER // CREATE PROCEDURE INS_T() BEGIN SET @i=1; WHILE 0<1 DO SET @i=@i+1; INSERT INTO i VALUES (1199116800+@i, FROM_UNIXTIME(1199116800+@i), FROM_UNIXTIME(1199116800+@i)); END WHILE; END;// DELIMITER ;
时间戳 1199116800 表示 2008-01-01 这个时间点。然后运行存储过程,大概填充几十万条记录后,中止执行,因为上面的存储过程是个死循环,所以需要人工中止。
来看看到底有多少条记录了,以及索引情况:
mysql> select count(*) from t; +----------+ | count(*) | +----------+ | 924707 | +----------+ mysql> analyze table t; +--------+---------+----------+-----------------------------+ | Table | Op | Msg_type | Msg_text | +--------+---------+----------+-----------------------------+ | test.t | analyze | status | Table is already up to date | +--------+---------+----------+-----------------------------+ mysql> show index from t; +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+ | Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+ | t | 1 | d2 | 1 | d2 | A | 924707 | NULL | NULL | | BTREE | | | t | 1 | d1 | 1 | d1 | A | 924707 | NULL | NULL | | BTREE | | | t | 1 | d3 | 1 | d3 | A | 924707 | NULL | NULL | | BTREE | | +-------+------------+----------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
2. 对比
2.1 只检索一条记录
mysql> explain select * from t where d1 = 1199579155; +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | 1 | SIMPLE | t | ref | d1 | d1 | 4 | const | 1 | | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ mysql> explain select * from t where d2 = '2008-01-06 08:25:55'; +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | 1 | SIMPLE | t | ref | d2 | d2 | 4 | const | 1 | | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ mysql> explain select * from t where d3 = '2008-01-06 08:25:55'; +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+ | 1 | SIMPLE | t | ref | d3 | d3 | 8 | const | 1 | | +----+-------------+-------+------+---------------+------+---------+-------+------+-------+
2.2 范围检索
mysql> explain select * from t where d1 >= 1199894400; +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | 1 | SIMPLE | t | range | d1 | d1 | 4 | NULL | 121961 | Using where | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ mysql> explain select * from t where d2 >= from_unixtime(1199894400); +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | 1 | SIMPLE | t | range | d2 | d2 | 4 | NULL | 121961 | Using where | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ mysql> explain select * from t where d3 >= from_unixtime(1199894400); +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+ | 1 | SIMPLE | t | range | d3 | d3 | 8 | NULL | 120625 | Using where | +----+-------------+-------+-------+---------------+------+---------+------+--------+-------------+
小结:从上面的2次对比中可以看到,对 d1 或 d2 字段检索时的索引长度都是 4,因为 TIMESTAMP 实际上是 4字节 的 INT 值。因此,实际应用中,基本上完全可以采用 TIMESTAMP 来代替另外2种类型了,并且 TIMESTAMP 还能支持自动更新成当前最新时间,何乐而不为呢?
评论
游客 (未验证)
周一, 2009/04/27 - 16:04
Permalink
问下。。。怎么调用
问下。。。怎么调用那个存储过程。。。我直接call INS_T();的。。。
俺是新手别见笑。。。
游客 (未验证)
周一, 2009/04/27 - 17:19
Permalink
- - 打扰了
- - 打扰了 已经知道了
网络名称 (未验证)
周日, 2010/02/07 - 21:40
Permalink
SET @i=@i+1; INSERT INTO i
SET @i=@i+1;
INSERT INTO i VALUES (1199116800+@i, FROM_UNIXTIME(1199116800+@i), FROM_UNIXTIME(1199116800+@i));
END WHILE;
顺道说一句是 INTO t 不是into i
小bug
外带,blog那个注册邮件貌似是发不过来了。。。
yejr
周一, 2010/02/08 - 09:25
Permalink
呵呵,有需要给我留
呵呵,有需要给我留言或单独发mail,我给你手工改密码 :)
游客 (未验证)
周六, 2010/07/17 - 02:43
Permalink
第一种和第二种有什
第一种和第二种有什么区别呢
半瓶 (未验证)
周三, 2010/08/04 - 09:45
Permalink
timestamp是有范围的,
timestamp是有范围的,只能从1970到2037,实际应用中不能完全替代其他的格式。
seven (未验证)
周四, 2010/10/21 - 22:10
Permalink
恩 因为疑问
恩 因为疑问 搜索答案来到这里
谢谢你的实验数据..
乌云 (未验证)
周五, 2010/11/05 - 11:54
Permalink
有些疑问 既然你说“T
有些疑问
既然你说“TIMESTAMP 实际上是 4字节 的 INT 值”,
索引是4字节,那也应该是Int了吧?
那SQL语句中where段中跟TIMESTAMP 比较的,
需要是一个字符串,问题就在这里了:
字符串跟Int比较,是将字符串转成Int去对比,还是Int转字符串去对比呢?
如果是字符串对比的话,是不是用ascii码比对呢?
用INT存时间的是不是会更好呢?
小弟试过两种格式的表都插入100万条记录,表大小是一样的,也就是说,TIMESTAMP 的保存形式应该是Int,而不是char。
where语句中的比较,应该是将字符串转为Int来比较的。
欢迎与我交流darkcloud783@126.com
www.5dphp.com
另外,我想问一下楼主,你那个方法插入100万条记录需要多长时间?