Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  Using AUTO_INCREMENT


The AUTO_INCREMENT attribute can be used to generate a unique identity for new rows:

CREATE TABLE animals (
     name CHAR(30) NOT NULL,
     PRIMARY KEY (id)

INSERT INTO animals (name) VALUES

SELECT * FROM animals;

Which returns:

| id | name    |
|  1 | dog     |
|  2 | cat     |
|  3 | penguin |
|  4 | lax     |
|  5 | whale   |
|  6 | ostrich |

No value was specified for the AUTO_INCREMENT column, so MySQL assigned sequence numbers automatically. You can also explicitly assign 0 to the column to generate sequence numbers. If the column is declared NOT NULL, it is also possible to assign NULL to the column to generate sequence numbers. When you insert any other value into a AUTO_INCREMENT column, the column is set to that value and the sequence is reset so that the next automatically generated value follows sequentially from the inserted value.

You can retrieve the most recent automatically generated AUTO_INCREMENT value with the LAST_INSERT_ID() SQL function or the mysql_insert_id() C API function. These functions are connection-specific, so their return values are not affected by another connection which is also performing inserts.

Use the smallest integer data type for the AUTO_INCREMENT column that is large enough to hold the maximum sequence value you will need. When the column reaches the upper limit of the data type, the next attempt to generate a sequence number fails. Use the UNSIGNED attribute if possible to allow a greater range. For example, if you use TINYINT, the maximum permissible sequence number is 127. For TINYINT UNSIGNED, the maximum is 255. See Section 11.2.1, “Integer Types (Exact Value) - INTEGER, INT, SMALLINT, TINYINT, MEDIUMINT, BIGINT” for the ranges of all the integer types.


For a multiple-row insert, LAST_INSERT_ID() and mysql_insert_id() actually return the AUTO_INCREMENT key from the first of the inserted rows. This enables multiple-row inserts to be reproduced correctly on other servers in a replication setup.

To start with an AUTO_INCREMENT value other than 1, set that value with CREATE TABLE or ALTER TABLE, like this:


InnoDB Notes

For InnoDB tables, be careful if you modify the column containing the auto-increment value in the middle of a sequence of INSERT statements. For example, if you use an UPDATE statement to put a new, larger value in the auto-increment column, a subsequent INSERT could encounter a Duplicate entry error. The test whether an auto-increment value is already present occurs if you do a DELETE followed by more INSERT statements, or when you COMMIT the transaction, but not after an UPDATE statement.

For more information about AUTO_INCREMENT and InnoDB, see Section 14.5.5, “AUTO_INCREMENT Handling in InnoDB”.

MyISAM Notes

  • For MyISAM tables, you can specify AUTO_INCREMENT on a secondary column in a multiple-column index. In this case, the generated value for the AUTO_INCREMENT column is calculated as MAX(auto_increment_column) + 1 WHERE prefix=given-prefix. This is useful when you want to put data into ordered groups.

    CREATE TABLE animals (
        grp ENUM('fish','mammal','bird') NOT NULL,
        name CHAR(30) NOT NULL,
        PRIMARY KEY (grp,id)
    INSERT INTO animals (grp,name) VALUES
    SELECT * FROM animals ORDER BY grp,id;

    Which returns:

    | grp    | id | name    |
    | fish   |  1 | lax     |
    | mammal |  1 | dog     |
    | mammal |  2 | cat     |
    | mammal |  3 | whale   |
    | bird   |  1 | penguin |
    | bird   |  2 | ostrich |

    In this case (when the AUTO_INCREMENT column is part of a multiple-column index), AUTO_INCREMENT values are reused if you delete the row with the biggest AUTO_INCREMENT value in any group. This happens even for MyISAM tables, for which AUTO_INCREMENT values normally are not reused.

  • If the AUTO_INCREMENT column is part of multiple indexes, MySQL generates sequence values using the index that begins with the AUTO_INCREMENT column, if there is one. For example, if the animals table contained indexes PRIMARY KEY (grp, id) and INDEX (id), MySQL would ignore the PRIMARY KEY for generating sequence values. As a result, the table would contain a single sequence, not a sequence per grp value.

Further Reading

More information about AUTO_INCREMENT is available here:

Download this Manual
User Comments
  Posted by Guy Martin on June 19, 2003
For those that are looking to "reset" the auto_increment, say on a list that has had a few deletions and you want to renumber everything, you can do the following.

DROP the field you are auto_incrementing.
ALTER the table to ADD the field again with the same attributes.

You will notice that all existing rows are renumbered and the next auto_increment number will be equal to the row count plus 1.

(Keep in mind that DROPping that column will remove all existing data, so if you have exterior resources that rely on that data, or the numbers that are already there, you may break the link. Also, as with any major structure change, it's a good idea to backup your table BEFORE you make the change.)
  Posted by on June 22, 2003
In order to reset the auto_increment, in a situation where some of the most recently added rows were deleted, use:


and future insertions will be numbered from 1234 again (unless you still had rows numbered greater than 1234, and then the future insertions will start from the greatest number + 1 ).

  Posted by on October 23, 2003
The manual should probably make *better* mention of the fact that the order in which primary keys are specified determines the semantics by which a new value is selected. (Saying "... is calculated as MAX(auto_increment_column)+1) WHERE prefix=given-prefix." is unclear given that this is the first mention of the word "prefix" in the document.

For example,

create table location
id bigint not null auto_increment, -- "serial" per 4.1
longitude int,
latitude int,
place int,
primary key(id, longitude, latitude, place)

insert into location (longitude, latitude, place)
values (0,0,0), (1,1,1), (2,2,2);

select * from foo;
| id | longitude | latitude | place |
| 1 | 0 | 0 | 0 |
| 2 | 1 | 1 | 1 |
| 3 | 2 | 2 | 2 |

drop table location;

create table location
id bigint not null auto_increment, -- "serial" per 4.1
longitude int,
latitude int,
place int,
primary key(longitude, latitude, place, id)

insert into location (longitude, latitude, place)
values (0,0,0), (1,1,1), (2,2,2), (0,0,0);

select * from location order by id;
| id | longitude | latitude | place |
| 1 | 0 | 0 | 0 |
| 1 | 1 | 1 | 1 |
| 1 | 2 | 2 | 2 |
| 2 | 0 | 0 | 0 |

Unless I've misunderstood (please correct me if I'm wrong), it's a nice feature but should be better documented than it is.



  Posted by on November 8, 2004
Drop table command will also reset autoincrement
  Posted by nav on February 7, 2006
reset auto_increment using....

alter table "table_name" auto_increment=1
resets auto_increment to 1 + max(auto_increment)
  Posted by kernel panic on March 24, 2008
Another way to get the next Auto_increment value is using the information_schema:

SELECT Auto_increment FROM information_schema.tables WHERE table_name='the_table_you_want';
  Posted by Gabe Holmes on July 12, 2009
If you're using a phpmyadmin, go to the table in question and then Operations->Table Options->Auto-Increment
Set the auto-increment to whatever you please.

Remember to check any foreign keys before doing anything serious, brush your teeth every day and wear sunscreen at the beach.
  Posted by Lewis Graham on August 26, 2009
InnoDB resets the next auto_increment value to the highest value in the table + 1 after a server restart.
This means that if you delete the highest value(s) in the table, then restart you can get the same values for auto_increment again.

  Posted by Luke Up on March 7, 2011
To reset auto_increment to 1, first make a backup of your table. I usually make 2 backups by copying my table 2 times (different names). Using one of the copies, delete the auto_increment field. Then run - ALTER TABLE `table_name` ADD `auto_increment_field` INT( 6 ) NOT NULL AUTO_INCREMENT FIRST, ADD PRIMARY KEY ( `auto_increment_field` ); If it works, Rename the original table to table_save and rename your modified table to the original table. Tested on phpmyadmin and mysql cli. Hope this helps.

  Posted by Daniel Bartley on June 29, 2011
-- Usage:
-- ResetTableIdentities('your_table_name');
-- Description:
-- Resets the Auto_Increment of the table [your_table_name] only when the number of rows in the [your_table_name] is equal to 0


CREATE DEFINER=`root`@`%` PROCEDURE `ResetTableIdentities`(IN table_name VARCHAR(64))
SET @returned_row_count = 0;
SET @table_name = table_name;

SET @statement = CONCAT("SELECT COUNT(*) INTO @returned_row_count FROM ", @table_name, ";");
PREPARE stmt FROM @statement;

IF (@returned_row_count = 0) THEN
SET @statement2 = CONCAT("ALTER TABLE ", @table_name, " AUTO_INCREMENT = 1;");
PREPARE stmt2 FROM @statement2;
EXECUTE stmt2;

  Posted by Sohail Khurshid on August 8, 2011
What's the point of mentioning such huge 'workarounds' when the auto_increment reset issue can be resolved simply by: "alter table "table_name" auto_increment=1" (as a couple of other people suggested too)?
  Posted by Thomas Mayer on January 20, 2012
As InnoDb forgets its highest auto_increment after server restart, you can set it again, if you have stored it anywhere. This happens often if you archive your data in an archive table and then delete it and then restart mysql. When archiving again this will result in duplicate key entries.

To work around this you can create a trigger which makes sure your auto_increment is higher than the auto_increment of your archive table:

delimiter //
drop trigger if exists trigger_autoinc_tbl;
CREATE TRIGGER trigger_autoinc_tbl BEFORE INSERT ON tbl
declare auto_incr1 BIGINT;
declare auto_incr2 BIGINT;
SELECT AUTO_INCREMENT INTO auto_incr1 FROM information_schema.TABLES WHERE table_schema=DATABASE() AND table_name='tbl';
SELECT AUTO_INCREMENT INTO auto_incr2 FROM information_schema.TABLES WHERE table_schema=DATABASE() AND table_name='tbl_archiv';
IF (auto_incr2 > auto_incr1 and<auto_incr2) THEN
SET = auto_incr2;
delimiter ;

Further reading:
  Posted by Anil Purushothaman on October 10, 2012
When using MySQL Workbench, you can reset the auto increment to 1 as follows -
Step 1 : In SQL Editor window, right click on the table name containing the auto increment field and select "Alter Table..."
Step 2 : Select "options" table in the alter table window pane.
Step 3 : The Auto Increment field here shows the current value that it has reached. Simply change it to the value you want (1 in this case).
Step 4 : Apply and close.
  Posted by Asromi rOmi on October 3, 2014
Try this one ..

Alter Table [TableName] add [newColoum] int auto_increment primary key;

it will add one coloum in the table as auto_increment.


desc [TableName];
  Posted by Charles Peterson on November 14, 2014
Note on finding all the tables with auto increment columns....
Sign Up Login You must be logged in to post a comment.