We know that copying a table into another using the SELECT…INTO statement copies over the IDENTITY property also. However, it is possible that one might want to use an IDENTITY specification different from the source table in this process.
This can be achieved using the IDENTITY() function, which allows us to create a new column for the destination table when used with the SELECT…INTO clause. The function accepts upto 3 parameters – the data-type, the Identity seed and the Identity increment values for the new column.
The process described in this post can also be used to define an IDENTITY column in the destination table when the source table does not have one.
IDENTITY() – Demo
The script below demonstrates the usage of the IDENTITY column. I do not have an IDENTITY column on the source table. During the SELECT…INTO process, I wanted to create the new table with an IDENTITY specification in-place. To do so, I used the IDENTITY() function.
USE tempdb; GO SET NOCOUNT ON; --1. Prepare the environment -- Create a table, and add some test data into it --Safety Check IF OBJECT_ID('tIdentity','U') IS NOT NULL DROP TABLE dbo.tIdentity; GO --Create a table, notice that there are NO Identity columns on this table CREATE TABLE dbo.tIdentity ( IdentityValue VARCHAR(10) ); GO --Add some test data INSERT INTO dbo.tIdentity (IdentityValue) VALUES ('One'), ('Two'), ('Three'), ('Four'), ('Five'); GO --2. Use SELECT..INTO to bulk insert data to a new table SELECT IDENTITY(INT,100,1) AS DestinationId, SourceTable.IdentityValue AS DestinationValue INTO dbo.DestinationTable FROM dbo.tIdentity AS SourceTable ; --2a. Fetch the value inserted into the destination table SELECT DestinationTable.DestinationId, DestinationTable.DestinationValue FROM dbo.DestinationTable; --3. Check the properties of the new column - is it an IDENTITY column? SELECT sc.name AS ColumnName, OBJECT_NAME(sc.object_id) AS TableName, sic.seed_value AS IdentitySeed, sic.increment_value AS IdentityIncrement, sic.is_nullable AS IsNullable, sic.last_value AS LastIdentityValueUsed FROM sys.columns AS sc INNER JOIN sys.identity_columns AS sic ON sc.object_id = sic.object_id AND sc.column_id = sic.column_id WHERE ( sc.object_id = OBJECT_ID(N'dbo.DestinationTable',N'U') OR sc.object_id = OBJECT_ID(N'dbo.tIdentity',N'U') ) AND sc.is_identity = 1; --4. Cleanup IF OBJECT_ID('dbo.tIdentity','U') IS NOT NULL DROP TABLE dbo.tIdentity; GO IF OBJECT_ID('dbo.DestinationTable','U') IS NOT NULL DROP TABLE dbo.DestinationTable; GO /********************************************** RESULTS **********************************************/ /* DestinationId DestinationValue ------------- ---------------- 100 One 101 Two 102 Three 103 Four 104 Five ColumnName TableName IdentitySeed IdentityIncrement IsNullable LastIdentityValueUsed -------------- ----------------- ------------- ------------------ ---------- ---------------------- DestinationId DestinationTable 100 1 0 104 */
Using IDENTITY() without SELECT…INTO – Msg 177
IDENTITY() does appear to be a very useful function, but please be aware that it cannot be used outside the SELECT…INTO clause. This can be confirmed by a simple modification to the SELECT query used in the example above:
SELECT IDENTITY(INT,100,1) AS DestinationId, SourceTable.IdentityValue AS DestinationValue FROM dbo.tIdentity AS SourceTable ;
Executing this statement (assuming that the dependent tables and data is in-place) returns the following error:
Msg 177, Level 15, State 1, Line 16
The IDENTITY function can only be used when the SELECT statement has an INTO clause.
Conclusion
As can be seen from the scripts above, the IDENTITY() function is very useful to define domain/product-specific IDENTITY specification when importing data from one table to another.
Until we meet next time,
Pingback: #0390 – SQL Server – SSIS – OLE DB Destination – Table Fast Load – Keep Identity option | SQLTwins by Nakul Vachhrajani