May 26, 2010 at 9:57 am
We have a table with millions of records. The first column looks like 1,2,3,4,5,6....
but it is not an identity field. We want to change it to an identify field.
The only way I know to do this is "in-elegant" (e.g. create a temp table with that field as an Identity, copy the data to the new table, delete the original table, and rename the temp table back to the original name)
Is there a more "elegant" way (e.g. some "magic" DDL I'm not familiar with?) to do this task?
TIA,
Barkingdog
May 26, 2010 at 10:40 am
Is the current column defined as NOT NULL? If so, there is a neat trick that makes it almost instant regardless of the number of rows.
Table definition please (including indexes).
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
May 26, 2010 at 2:15 pm
Paul,
The column is defined as NOT NULL and there are no indexes or constraints defined on the table.
Barkingdog
May 26, 2010 at 3:25 pm
Paul White NZ (5/26/2010)
Is the current column defined as NOT NULL? If so, there is a neat trick that makes it almost instant regardless of the number of rows.Table definition please (including indexes).
I'm ready to see this myself... [learn]
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
May 26, 2010 at 8:29 pm
WayneS (5/26/2010)
Paul White NZ (5/26/2010)
Is the current column defined as NOT NULL? If so, there is a neat trick that makes it almost instant regardless of the number of rows.Table definition please (including indexes).
I'm ready to see this myself... [learn]
Me too waiting for the answer from Paul!
May 27, 2010 at 3:35 am
Demonstration script (any edition of 2005+ required)
USE tempdb;
GO
-- Source table without IDENTITY
-- (PRIMARY KEY just for demonstration purposes)
CREATE TABLE dbo.Example
(
row_id BIGINT NOT NULL
CONSTRAINT [PK dbo.Example row_id]
PRIMARY KEY CLUSTERED,
data INTEGER NOT NULL
);
GO
-- Add 987,000 rows (takes about 15-20 seconds)
INSERT dbo.Example WITH (TABLOCK)
SELECT TOP 987000
ROW_NUMBER() OVER (ORDER BY (SELECT 0)),
CHECKSUM(NEWID())
FROM master.sys.all_columns A1,
master.sys.all_columns A2,
master.sys.all_columns A3;
GO
-- New shadow empty table with IDENTITY
CREATE TABLE dbo.ExampleIdentity
(
row_id BIGINT NOT NULL
IDENTITY(1,1)
CONSTRAINT [PK dbo.ExampleIdentity row_id]
PRIMARY KEY CLUSTERED,
data INTEGER NOT NULL
);
GO
-- Promote almost all errors to automatic transaction aborts
SET XACT_ABORT ON;
-- Transaction for safety
BEGIN TRANSACTION;
-- Move the rows (instant)
ALTER TABLE dbo.Example
SWITCH TO dbo.ExampleIdentity;
-- Drop the empty original table (also instant)
DROP TABLE dbo.Example;
-- Rename the new table as the old table
EXECUTE sp_rename @objname = N'dbo.ExampleIdentity', @newname = N'Example', @objtype = 'OBJECT';
-- Rename the PRIMARY KEY
EXECUTE sp_rename @objname = N'dbo.Example.[PK dbo.ExampleIdentity row_id]', @newname = N'PK dbo.Example row_id', @objtype = 'INDEX';
COMMIT TRANSACTION;
-- Show some rows
SELECT TOP (10) *
FROM dbo.Example;
-- Show IDENTITY properties (notice last_value is NULL)
SELECT OBJECT_NAME([object_id]),
TYPE_NAME(system_type_id),
seed_value,
increment_value,
last_value
FROM sys.identity_columns
WHERE [object_id] = OBJECT_ID(N'dbo.Example', N'U');
-- Fix up the IDENTITY metadata
DBCC CHECKIDENT(N'dbo.Example', 'RESEED');
-- Show IDENTITY properties (last_value is now 987,000)
SELECT OBJECT_NAME([object_id]),
TYPE_NAME(system_type_id),
seed_value,
increment_value,
last_value
FROM sys.identity_columns
WHERE [object_id] = OBJECT_ID(N'dbo.Example', N'U');
-- Tidy up
DROP TABLE dbo.Example;
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
May 27, 2010 at 3:40 am
Liking the SWITCH
option... Used it many times.
Nice code!
May 27, 2010 at 6:03 am
sql_lock (5/27/2010)
Liking theSWITCH
option... Used it many times.Nice code!
Curious... Other than the obvious purpose for partitioned tables documented in BOL or the one that Paul laid out above, have you used it for anything else?
--Jeff Moden
Change is inevitable... Change for the better is not.
May 27, 2010 at 6:42 am
Jeff Moden (5/27/2010)
sql_lock (5/27/2010)
Liking theSWITCH
option... Used it many times.Nice code!
Curious... Other than the obvious purpose for partitioned tables documented in BOL or the one that Paul laid out above, have you used it for anything else?
Jeff
It is in DW for staged data loading and archiving base on our financial year. Not the ideal, but works we for us.
Cheers
May 27, 2010 at 6:57 am
Thanks for the feedback.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply