AUTO_INCREMENT on a secondary column in a multiple-column index

本文涉及的产品
云数据库 RDS MySQL Serverless,0.5-2RCU 50GB
简介:
MySQL中可以通过AUTO_INCREMENT产生自增长序列。
但是在MyISAM和InnoDB存储引擎中使用有点区别。
在MySQL 5.5.8中测试(默认存储引擎InnoDB),例如:
mysql> create table tbl_test (id int not null auto_increment,firstname varchar(32),lastname varchar(32),primary key (firstname,id));
ERROR 1075 (42000): Incorrect table definition; there can be only one auto column and it must be defined as a key

在InnoDB中AUTO_INCREMENT可以看作只有一个链。因此建表时报错, 看了MyISAM的举例就很容易理解.
mysql> create table tbl_test (id int not null auto_increment,firstname varchar(32),lastname varchar(32),primary key (firstname,id)) engine=MyISAM;
Query OK, 0 rows affected (0.03 sec)
mysql> insert into tbl_test(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> select * from tbl_test;
+----+-----------+----------+
| id | firstname | lastname |
+----+-----------+----------+
|  1 | zhou      | digoal   |
|  1 | Zhou      | digoal   |
|  2 | zhou      | Digoal   |
+----+-----------+----------+
3 rows in set (0.00 sec)

# 从结果来看 AUTO_INCREMENT 根据firstname的值 , 被拆成了多条链 ( 或者说有几个firstname的值就有几个链 ) 。
# 换个例子可能更好说明问题:
mysql> create table tbl_test1 (id int not null auto_increment,firstname varchar(32),lastname varchar(32),primary key (firstname,lastname,id)) engine=MyISAM;
Query OK, 0 rows affected (0.03 sec)
mysql> insert into tbl_test1(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> insert into tbl_test1(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> insert into tbl_test1(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> insert into tbl_test1(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> select * from tbl_test1;
+----+-----------+----------+
| id | firstname | lastname |
+----+-----------+----------+
|  1 | Zhou      | digoal   |
|  2 | Zhou      | digoal   |
|  3 | Zhou      | digoal   |
|  4 | Zhou      | digoal   |
|  1 | zhou      | Digoal   |
|  2 | zhou      | Digoal   |
|  3 | zhou      | Digoal   |
|  4 | zhou      | Digoal   |
|  1 | zhou      | digoal   |
|  2 | zhou      | digoal   |
|  3 | zhou      | digoal   |
|  4 | zhou      | digoal   |
+----+-----------+----------+
12 rows in set (0.00 sec)

# AUTO_INCREMENT 根据firstname,lastname的值 , 被拆成了多条链 ( 或者说有几个firstname,lastname的值组合就有几个链 ) 。

# 来看看把tbl_test的引擎转换为InnoDB会怎么样?
mysql> show table status like 'tbl_test' \G
*************************** 1. row ***************************
           Name: tbl_test
         Engine: MyISAM
        Version: 10
     Row_format: Dynamic
           Rows: 9
 Avg_row_length: 24
    Data_length: 216
Max_data_length: 281474976710655
   Index_length: 3072
      Data_free: 0
 Auto_increment: 9
    Create_time: 2011-01-17 15:52:50
    Update_time: 2011-01-17 15:52:54
     Check_time: NULL
      Collation: utf8_bin
       Checksum: NULL
 Create_options: 
        Comment: 
1 row in set (0.00 sec)

转换报错 :
mysql> alter table tbl_test engine=InnoDB;
ERROR 1075 (42000): Incorrect table definition; there can be only one auto column and it must be defined as a key

# 新建一个KEY就可以转换为InnoDB引擎.
mysql> create index idx_id on tbl_test(id);
Query OK, 3 rows affected (0.04 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> alter table tbl_test engine=innodb;
Query OK, 9 rows affected (0.08 sec)
Records: 9  Duplicates: 0  Warnings: 0

mysql> show table status like 'tbl_test' \G
*************************** 1. row ***************************
           Name: tbl_test
         Engine: InnoDB
        Version: 10
     Row_format: Compact
           Rows: 9
 Avg_row_length: 1820
    Data_length: 16384
Max_data_length: 0
   Index_length: 16384
      Data_free: 10485760
 Auto_increment: 9
    Create_time: 2011-01-17 15:55:48
    Update_time: NULL
     Check_time: NULL
      Collation: utf8_bin
       Checksum: NULL
 Create_options: 
        Comment: 
1 row in set (0.00 sec)

mysql> describe tbl_test
    -> ;
+-----------+-------------+------+-----+---------+----------------+
| Field     | Type        | Null | Key | Default | Extra          |
+-----------+-------------+------+-----+---------+----------------+
| id        | int(11)     | NO   | PRI | NULL    | auto_increment |
| firstname | varchar(32) | NO   | PRI |         |                |
| lastname  | varchar(32) | YES  |     | NULL    |                |
+-----------+-------------+------+-----+---------+----------------+
3 rows in set (0.00 sec)

mysql> show create table tbl_test;
+----------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table    | Create Table                                                                                                                                                                                                                                                                                                             |
+----------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| tbl_test | CREATE TABLE `tbl_test` (
  `id` int(11) NOT NULL AUTO_INCREMENT,
  `firstname` varchar(32) COLLATE utf8_bin NOT NULL DEFAULT '',
  `lastname` varchar(32) COLLATE utf8_bin DEFAULT NULL,
  PRIMARY KEY (`firstname`,`id`),
  KEY `idx_id` (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=utf8 COLLATE=utf8_bin |
+----------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.00 sec)

mysql> insert into tbl_test(firstname,lastname) values('zhou','digoal'),('Zhou','digoal'),('zhou','Digoal');
Query OK, 3 rows affected (0.03 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> select * from tbl_test;
+----+-----------+----------+
| id | firstname | lastname |
+----+-----------+----------+
|  1 | Zhou      | digoal   |
|  4 | Zhou      | digoal   |
|  7 | Zhou      | digoal   |
| 10 | Zhou      | digoal   |
|  1 | zhou      | digoal   |
|  2 | zhou      | Digoal   |
|  3 | zhou      | digoal   |
|  5 | zhou      | Digoal   |
|  6 | zhou      | digoal   |
|  8 | zhou      | Digoal   |
|  9 | zhou      | digoal   |
| 11 | zhou      | Digoal   |
+----+-----------+----------+
12 rows in set (0.00 sec)

# 转换为 InnoDB之后,AUTO_INCREMENT 变成单链自增。
相关实践学习
基于CentOS快速搭建LAMP环境
本教程介绍如何搭建LAMP环境,其中LAMP分别代表Linux、Apache、MySQL和PHP。
全面了解阿里云能为你做什么
阿里云在全球各地部署高效节能的绿色数据中心,利用清洁计算为万物互联的新世界提供源源不断的能源动力,目前开服的区域包括中国(华北、华东、华南、香港)、新加坡、美国(美东、美西)、欧洲、中东、澳大利亚、日本。目前阿里云的产品涵盖弹性计算、数据库、存储与CDN、分析与搜索、云通信、网络、管理与监控、应用服务、互联网中间件、移动服务、视频服务等。通过本课程,来了解阿里云能够为你的业务带来哪些帮助     相关的阿里云产品:云服务器ECS 云服务器 ECS(Elastic Compute Service)是一种弹性可伸缩的计算服务,助您降低 IT 成本,提升运维效率,使您更专注于核心业务创新。产品详情: https://www.aliyun.com/product/ecs
相关文章
|
9月前
|
关系型数据库 数据库 PostgreSQL
PG备份恢复:multiple primary keys for table "t1" are not allowed
PG备份恢复:multiple primary keys for table "t1" are not allowed
191 0
|
9月前
|
关系型数据库 MySQL 数据库
View ‘information_schema.SCHEMATA‘ references invalid table(s) or column(s) or function(s) or define
View ‘information_schema.SCHEMATA‘ references invalid table(s) or column(s) or function(s) or define
136 0
|
数据库
Incorrect table definition; there can be only one auto column and it must be defined as a key
Incorrect table definition; there can be only one auto column and it must be defined as a key
121 0
Incorrect table definition; there can be only one auto column and it must be defined as a key
|
存储 关系型数据库 MySQL
超详细!Mysql错误1452 - Cannot add or update a child row: a foreign key constraint fails 原因及解决方法
超详细!Mysql错误1452 - Cannot add or update a child row: a foreign key constraint fails 原因及解决方法
1451 0
超详细!Mysql错误1452 - Cannot add or update a child row: a foreign key constraint fails 原因及解决方法
|
存储 SQL 关系型数据库
mysql索引类型 normal, unique, full text
mysql索引类型 normal, unique, full text
178 0
|
SQL 关系型数据库 MySQL
Incorrect table definition; there can be only one TIMESTAMP column with CURRENT_TIMESTAMP in DEFAULT
Incorrect table definition; there can be only one TIMESTAMP column with CURRENT_TIMESTAMP in DEFAULT
|
关系型数据库 MySQL 数据库
MySQL问题解决:Cannot delete or update a parent row: a foreign key constraint fails
MySQL问题解决:Cannot delete or update a parent row: a foreign key constraint fails
976 0
|
关系型数据库 MySQL
Mysql - 删除表时出现: Cannot delete or update a parent row: a foreign key constraint fails
Mysql - 删除表时出现: Cannot delete or update a parent row: a foreign key constraint fails
185 0
when is status text joined in column search engine
when is status text joined in column search engine
97 0
when is status text joined in column search engine