December 27, 2012 at 8:35 am
Using the simplest SELECT INTO syntax, the IDENTITY property of a column is part of the definition of the destination table. Is there a simple way to avoid this? I can't seem to find anything in the documentation, or my google-foo is deficient.
I'm trying to create an mirror image of a table, using a false WHERE clause to create only the table structure.
December 27, 2012 at 8:37 am
Why not drop the column after creation and before putting anything in it?
______________________________________________________________________
Personal Motto: Why push the envelope when you can just open it?
If you follow the direction given HERE[/url] you'll likely increase the number and quality of responses you get to your question.
Jason L. SelburgDecember 27, 2012 at 8:41 am
I want a clone of the table (with 3 addition, preceeding, columns), with the original column sequence, if possible. I'd rather not have to resort to dynamic SQL to define the table, but the presence of the IDENTITY attribute is a "deal killer", since the purpose is short-term "before / after" storage for content changes.
December 27, 2012 at 8:42 am
What you described would create that mirror image. If you just not want to have the identity column in the new table, you can simply exclude it from the select list.
create table #Source
(
SourceID int identity,
SomeValue varchar(10)
)
insert #Source
select 'Source 1' union all
select 'Source 2'
select *
into #Test
from #Source
where 1 = 2
insert #Test
select 'Test'
select * from #Test
drop table #Source
drop table #Test
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
December 27, 2012 at 8:46 am
PhilPacha (12/27/2012)
Using the simplest SELECT INTO syntax, the IDENTITY property of a column is part of the definition of the destination table. Is there a simple way to avoid this? I can't seem to find anything in the documentation, or my google-foo is deficient.I'm trying to create an mirror image of a table, using a false WHERE clause to create only the table structure.
It's easy. Just recast the column as an INT during the SELECT/INTO. If you want it to be a NOT NULL column, just wrap an ISNULL around that...
SELECT SomeBasicIntColumn = ISNULL(CAST(SomeIdentityColumn AS INT),0),
other columns
INTO #SomeTempTable
FROM dbo.SomeOtherTable
WHERE 1 = 0
;
--Jeff Moden
Change is inevitable... Change for the better is not.
December 27, 2012 at 8:53 am
Thanks Jeff. I was hoping for something which could use "SELECT *", so knowledge about the extant columns wouldn't be necessary. Neat technique, though, if the column names and the column with the IDENTITY attribute are known in advance. I'll add this bit to my "tool box".
December 31, 2012 at 2:40 pm
Please try this:
SELECT *
INTO dbo.newtable
FROM dbo.oldtable_with_identity
UNION ALL
SELECT TOP (1) *
FROM dbo.oldtable_with_identity
WHERE 1 = 0
The identity property should be left off the column in the new table :-).
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
December 31, 2012 at 3:27 pm
deleted
______________________________________________________________________
Personal Motto: Why push the envelope when you can just open it?
If you follow the direction given HERE[/url] you'll likely increase the number and quality of responses you get to your question.
Jason L. SelburgDecember 31, 2012 at 4:11 pm
ScottPletcher (12/31/2012)
Please try this:
SELECT *
INTO dbo.newtable
FROM dbo.oldtable_with_identity
UNION ALL
SELECT TOP (1) *
FROM dbo.oldtable_with_identity
WHERE 1 = 0
The identity property should be left off the column in the new table :-).
Nicely done, Scott. You can also get away without using the TOP (1). The cpu time used and the number of reads are identical.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 31, 2012 at 4:29 pm
Jeff Moden (12/27/2012)
PhilPacha (12/27/2012)
Using the simplest SELECT INTO syntax, the IDENTITY property of a column is part of the definition of the destination table. Is there a simple way to avoid this? I can't seem to find anything in the documentation, or my google-foo is deficient.I'm trying to create an mirror image of a table, using a false WHERE clause to create only the table structure.
It's easy. Just recast the column as an INT during the SELECT/INTO. If you want it to be a NOT NULL column, just wrap an ISNULL around that...
SELECT SomeBasicIntColumn = ISNULL(CAST(SomeIdentityColumn AS INT),0),
other columns
INTO #SomeTempTable
FROM dbo.SomeOtherTable
WHERE 1 = 0
;
You can also do this with an integer expression
SELECT SomeBasicIntColumn = 0 + SomeIdentityColumn,
other columns
INTO #SomeTempTable
FROM dbo.SomeOtherTable
WHERE 1 = 0
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537January 3, 2013 at 9:22 am
Thank you, Scott! With the addition of a WHERE clause on the first SELECT, I end up with an empty table without a IDENTITY property, which is EXACTLY what I was looking for. Prefacing the * with my additional control columns doesn't mess up the solution, either. SSC rules!
March 28, 2017 at 3:11 am
Wonderful solution, thank you!!
July 13, 2018 at 3:10 pm
ScottPletcher - Monday, December 31, 2012 2:40 PM
SELECT *INTO dbo.newtable
FROM dbo.oldtable_with_identity
UNION ALL
SELECT TOP (1) *
FROM dbo.oldtable_with_identity
WHERE 1 = 0
I was able to get an empty table without IDENTITY with this similar query.select * into ##Rec from dbo.Records where 1 = 0
union all
select * from dbo.Records where 1 = 0
;
Sincerely,
Daniel
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply