Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Allows explicit values to be inserted into the identity column of a table.
Transact-SQL syntax conventions
SET IDENTITY_INSERT [ [ database_name . ] schema_name . ] table_name { ON | OFF }
The name of the database in which the specified table resides.
The name of the schema to which the table belongs.
The name of a table with an identity column.
At any time, only one table in a session can have the IDENTITY_INSERT
property set to ON
. If a table already has this property set to ON
, and a SET IDENTITY_INSERT ON
statement is issued for another table, SQL Server returns an error message that states SET IDENTITY_INSERT
is already ON
, and reports the table for which ON
is set.
If the value inserted is larger than the current identity value for the table, SQL Server automatically uses the new inserted value as the current identity value.
The setting of SET IDENTITY_INSERT
is set at execute or run time and not at parse time.
User must own the table or have ALTER
permission on the table.
The following example creates a table with an identity column and shows how the SET IDENTITY_INSERT
setting can be used to fill a gap in the identity values caused by a DELETE
statement.
USE AdventureWorks2022;
GO
Create tool table.
CREATE TABLE dbo.Tool
(
ID INT IDENTITY NOT NULL PRIMARY KEY,
Name VARCHAR (40) NOT NULL
);
GO
Insert values into products table.
INSERT INTO dbo.Tool (Name)
VALUES ('Screwdriver'),
('Hammer'),
('Saw'),
('Shovel');
GO
Create a gap in the identity values.
DELETE dbo.Tool
WHERE Name = 'Saw';
GO
SELECT *
FROM dbo.Tool;
GO
Try to insert an explicit ID value of 3.
INSERT INTO dbo.Tool (ID, Name)
VALUES (3, 'Garden shovel');
GO
The previous INSERT
code should return the following error:
An explicit value for the identity column in table 'AdventureWorks2022.dbo.Tool' can only be specified when a column list is used and IDENTITY_INSERT is ON.
Set IDENTITY_INSERT
to ON
.
SET IDENTITY_INSERT dbo.Tool ON;
GO
Try to insert an explicit ID value of 3.
INSERT INTO dbo.Tool (ID, Name)
VALUES (3, 'Garden shovel');
GO
SELECT *
FROM dbo.Tool;
GO
Drop tool table.
DROP TABLE dbo.Tool;
GO
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register today