Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

SELECT * INTO Table without propagating IDENTITY attribute? Expand / Collapse
Author
Message
Posted Thursday, December 27, 2012 8:35 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 12:08 PM
Points: 363, Visits: 2,341
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.



Post #1400640
Posted Thursday, December 27, 2012 8:37 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Sunday, October 5, 2014 10:21 AM
Points: 2,717, Visits: 3,855
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 you'll likely increase the number and quality of responses you get to your question.

Jason L. Selburg
Post #1400642
Posted Thursday, December 27, 2012 8:41 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 12:08 PM
Points: 363, Visits: 2,341
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.


Post #1400645
Posted Thursday, December 27, 2012 8:42 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 11:50 AM
Points: 13,082, Visits: 12,547
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1400648
Posted Thursday, December 27, 2012 8:46 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:53 PM
Points: 35,366, Visits: 31,905
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1400651
Posted Thursday, December 27, 2012 8:53 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 12:08 PM
Points: 363, Visits: 2,341
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".


Post #1400653
Posted Monday, December 31, 2012 2:40 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 4:17 PM
Points: 2,197, Visits: 3,308
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)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1401510
Posted Monday, December 31, 2012 3:27 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Sunday, October 5, 2014 10:21 AM
Points: 2,717, Visits: 3,855
deleted

______________________________________________________________________

Personal Motto: Why push the envelope when you can just open it?

If you follow the direction given HERE you'll likely increase the number and quality of responses you get to your question.

Jason L. Selburg
Post #1401517
Posted Monday, December 31, 2012 4:11 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:53 PM
Points: 35,366, Visits: 31,905
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1401521
Posted Monday, December 31, 2012 4:29 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Friday, October 3, 2014 1:38 AM
Points: 1,678, Visits: 19,553
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



____________________________________________________

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1401523
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse