1. server_id 唯一并且对函数 uuid_short() 的调用次数不超过每秒 16777216 次,也就是 2^24。所以一般情况下,uuid_short 函数能保证结果唯一。2. uuid_short 函数生成的 ID 只需一个轻量级的 mutex 来保护,这点比自增 ID 需要的 auto-inc 表锁更省资源,生成结果肯定更加快速。下面表 t_uuid_short 演示了如何用这个函数。mysql> create table t_uuid_short (id bigint unsigned primary key,r1 int, key idx_r1(r1));
Query OK, 0 rows affected (0.06 sec)
mysql> insert into t_uuid_short values(uuid_short(),1),(uuid_short(),2)
Query OK, 2 rows affected (0.02 sec)
Records: 2 Duplicates: 0 Warnings: 0
mysql> select * from t_uuid_short;
+----------------------+------+
| id | r1 |
+----------------------+------+
| 16743984358464946177 | 1 |
| 16743984358464946178 | 2 |
+----------------------+------+
2 rows in set (0.00 sec)
可以看到 uuid_short 生成的数据是基于 INT64 有序的,所以这块可以看做是自增 ID 的一个补充优化,如果每秒调用次数少于 16777216,推荐用 uuid_short,而非自增 ID。说了那么多,还是简单验证下上面的结论,做个小实验。正如之前的预期,写性能差异按从最差到最好排列依次为:t_uuid; t_binary;t_id;t_uuid_short。我们来实验下是否和预期相符。mysql> create table t_uuid(id char(36) primary key, r1 int, key idx_r1(r1));
Query OK, 0 rows affected (0.06 sec)
mysql> create table t_id (id bigint auto_increment primary key, r1 int, key idx_r1(r1));
Query OK, 0 rows affected (0.08 sec)
简单写了一个存储过程,分别给这些表造 30W 条记录。DELIMITER $$
CREATE
PROCEDURE `ytt`.`sp_insert_data`(
f_tbname VARCHAR(64),
f_number INT UNSIGNED
)
BEGIN
DECLARE i INT UNSIGNED DEFAULT 0;
SET @@autocommit=0;
IF f_tbname = 't_uuid' THEN
SET @stmt = CONCAT('insert into t_uuid values (uuid(),ceil(rand()*100));');
ELSEIF f_tbname = 't_binary' THEN
SET @stmt = CONCAT('insert into t_binary values(uuid_to_bin(uuid()),ceil(rand()*100));');
ELSEIF f_tbname = 't_uuid_short' THEN
SET @stmt = CONCAT('insert into t_uuid_short values(uuid_short(),ceil(rand()*100));');
ELSEIF f_tbname = 't_id' THEN
SET @stmt = CONCAT('insert into t_id(r1) values(ceil(rand()*100));');
END IF;
WHILE i < f_number
DO
PREPARE s1 FROM @stmt;
EXECUTE s1;
SET i = i + 1;
IF MOD(i,50) = 0 THEN
COMMIT;
END IF;
END WHILE;
COMMIT;
DROP PREPARE s1;
SET @@autocommit=1;
END$$
DELIMITER ;
接下来分别调用存储过程,结果和预期一致。t_uuid 时间最长,t_uuid_short 时间最短。mysql> call sp_insert_data('t_uuid',300000);
Query OK, 0 rows affected (5 min 23.33 sec)
mysql> call sp_insert_data('t_binary',300000);
Query OK, 0 rows affected (4 min 48.92 sec)
mysql> call sp_insert_data('t_id',300000);
Query OK, 0 rows affected (3 min 40.38 sec)
mysql> call sp_insert_data('t_uuid_short',300000);
Query OK, 0 rows affected (3 min 9.94 sec)