Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 44.6Mb
PDF (A4) - 44.6Mb
PDF (RPM) - 40.3Mb
HTML Download (TGZ) - 10.5Mb
HTML Download (Zip) - 10.5Mb
HTML Download (RPM) - 9.1Mb
Man Pages (TGZ) - 204.6Kb
Man Pages (Zip) - 311.5Kb
Info (Gzip) - 3.9Mb
Info (Zip) - 3.9Mb
Excerpts from this Manual

MySQL 8.0 Reference Manual  /  ...  /  Using AUTO_INCREMENT

3.6.9 Using AUTO_INCREMENT

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

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

INSERT INTO animals (name) VALUES
    ('dog'),('cat'),('penguin'),
    ('lax'),('whale'),('ostrich');

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, unless the NO_AUTO_VALUE_ON_ZERO SQL mode is enabled. For example:

INSERT INTO animals (id,name) VALUES(0,'groundhog');

If the column is declared NOT NULL, it is also possible to assign NULL to the column to generate sequence numbers. For example:

INSERT INTO animals (id,name) VALUES(NULL,'squirrel');

When you insert any other value into an 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 largest column value. For example:

INSERT INTO animals (id,name) VALUES(100,'rabbit');
INSERT INTO animals (id,name) VALUES(NULL,'mouse');
SELECT * FROM animals;
+-----+-----------+
| id  | name      |
+-----+-----------+
|   1 | dog       |
|   2 | cat       |
|   3 | penguin   |
|   4 | lax       |
|   5 | whale     |
|   6 | ostrich   |
|   7 | groundhog |
|   8 | squirrel  |
| 100 | rabbit    |
| 101 | mouse     |
+-----+-----------+

Updating an existing AUTO_INCREMENT column value also resets the AUTO_INCREMENT sequence.

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.

Note

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:

mysql> ALTER TABLE tbl AUTO_INCREMENT = 100;

InnoDB Notes

For information about AUTO_INCREMENT usage specific to InnoDB, see Section 15.6.1.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,
        id MEDIUMINT NOT NULL AUTO_INCREMENT,
        name CHAR(30) NOT NULL,
        PRIMARY KEY (grp,id)
    ) ENGINE=MyISAM;
    
    INSERT INTO animals (grp,name) VALUES
        ('mammal','dog'),('mammal','cat'),
        ('bird','penguin'),('fish','lax'),('mammal','whale'),
        ('bird','ostrich');
    
    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:


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  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

DELIMITER $$

CREATE DEFINER=`root`@`%` PROCEDURE `ResetTableIdentities`(IN table_name VARCHAR(64))
BEGIN
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;
EXECUTE stmt;

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

DEALLOCATE PREPARE stmt2;
END IF;
DEALLOCATE PREPARE stmt;
END
  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
FOR EACH ROW
BEGIN
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 NEW.id<auto_incr2) THEN
SET NEW.id = auto_incr2;
END IF;
END;//
delimiter ;

Further reading: http://www.slicewise.net/index.php?id=82
  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.

check:

desc [TableName];
  Posted by Charles Peterson on November 14, 2014
Note on finding all the tables with auto increment columns....

http://blog.geekslikeshinythings.com/2014/11/find-all-autoincrement-tables.html
Sign Up Login You must be logged in to post a comment.