| Bug #72902 | auto increment value for table not affected by update statement | ||
|---|---|---|---|
| Submitted: | 6 Jun 2014 17:46 | Modified: | 6 Jun 2014 20:58 |
| Reporter: | Trey Raymond | Email Updates: | |
| Status: | Not a Bug | Impact on me: | |
| Category: | MySQL Server | Severity: | S3 (Non-critical) |
| Version: | 5.5.34 | OS: | Linux |
| Assigned to: | CPU Architecture: | Any | |
[6 Jun 2014 20:58]
MySQL Verification Team
Thank you for the bug report. Not repeatable with latest release 5.5.38. Please
upgrade.
c:\mysql-5.5.38-winx64>bin\mysql -uroot test
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 2
Server version: 5.5.38 MySQL Community Server (GPL)
Copyright (c) 2000, 2014, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
mysql> CREATE TABLE `test` (`id` int(10) unsigned NOT NULL, `a` varchar(10) NOT NULL,PRIMARY KEY (`id`),UNIQUE KEY `a` (`a`))
-> ENGINE=InnoDB DEFAULT CHARSET=utf8;
Query OK, 0 rows affected (0.11 sec)
mysql> insert into test (a) values ('hello');
Query OK, 1 row affected, 1 warning (0.03 sec)
mysql> alter table test modify id int(10) unsigned NOT NULL auto_increment;
Query OK, 1 row affected (0.25 sec)
Records: 1 Duplicates: 0 Warnings: 0
mysql> select * from test;
+----+-------+
| id | a |
+----+-------+
| 1 | hello |
+----+-------+
1 row in set (0.00 sec)

Description: see the how to repeat. when updating the auto increment value to one higher than the max in the table before, the table should set its autoinc to that value +1 (AUTO_INCREMENT=2), but it does not - it waits for an insert statement to do so. this causes the same insert statement executed twice in a row to fail once, succeed the second time. How to repeat: mysql> CREATE TABLE `test` ( -> `id` int(10) unsigned NOT NULL, -> `a` varchar(10) NOT NULL, -> PRIMARY KEY (`id`), -> UNIQUE KEY `a` (`a`) -> ) ENGINE=InnoDB DEFAULT CHARSET=utf8; Query OK, 0 rows affected (0.01 sec) mysql> insert into test (a) values ('hello'); Query OK, 1 row affected, 1 warning (0.00 sec) mysql> select * from test; +----+-------+ | id | a | +----+-------+ | 0 | hello | +----+-------+ 1 row in set (0.01 sec) mysql> alter table test modify id int(10) unsigned NOT NULL auto_increment; Query OK, 1 row affected (0.02 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql> select * from test; +----+-------+ | id | a | +----+-------+ | 0 | hello | +----+-------+ 1 row in set (0.00 sec) mysql> update test set id=1 where a='hello'; Query OK, 1 row affected (0.00 sec) Rows matched: 1 Changed: 1 Warnings: 0 mysql> select * from test; +----+-------+ | id | a | +----+-------+ | 1 | hello | +----+-------+ 1 row in set (0.00 sec) mysql> show create table test\G *************************** 1. row *************************** Table: test Create Table: CREATE TABLE `test` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `a` varchar(10) NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `a` (`a`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> insert into test (a) values ('world'); ERROR 1062 (23000): Duplicate entry '1' for key 'PRIMARY' mysql> select * from test; +----+-------+ | id | a | +----+-------+ | 1 | hello | +----+-------+ 1 row in set (0.00 sec) mysql> show create table test\G *************************** 1. row *************************** Table: test Create Table: CREATE TABLE `test` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `a` varchar(10) NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `a` (`a`) ) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> insert into test (a) values ('world'); Query OK, 1 row affected (0.00 sec) mysql> select * from test; +----+-------+ | id | a | +----+-------+ | 1 | hello | | 2 | world | +----+-------+ 2 rows in set (0.00 sec) mysql> show create table test\G *************************** 1. row *************************** Table: test Create Table: CREATE TABLE `test` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `a` varchar(10) NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `a` (`a`) ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8 1 row in set (0.00 sec) Suggested fix: ensure that an update which increases the max value of an auto increment column affects the tables stored auto-inc value. may be complex due to innodb autoinc lock modes.