SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Temp Tables revisited


Temp Tables revisited

Author
Message
Sergiy
Sergiy
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10298 Visits: 11960
Comments posted to this topic are about the item Temp Tables revisited
vinu512
vinu512
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1687 Visits: 1625
Good question on how parsing works.....very important to know the internals well.

Vinu Vijayan

For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden ;-)
Danny Ocean
Danny Ocean
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1614 Visits: 1549
Good basic question. But unfortunately, i have selected wrong one in hurry Pinch

Thanks
Vinay Kumar
-----------------------------------------------------------------
Keep Learning - Keep Growing !!!
www.GrowWithSql.com
kapil_kk
kapil_kk
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3069 Visits: 2766
Danny Ocean (6/23/2013)
Good basic question. But unfortunately, i have selected wrong one in hurry Pinch

+1

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
sharath.chalamgari
sharath.chalamgari
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1472 Visits: 798
what could be the better approach in this kind of situation , is there any better option than this


DECLARE @MoreColumns bit;
SET @MoreColumns = 1

Create table #table( id int )
IF @MoreColumns = 1
alter table #table
add col1 varchar(10)
ELSE
alter table #table
add col2 varchar(10)
DROP TABLE #Table



sharath.chalamgari
sharath.chalamgari
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1472 Visits: 798
http://support.microsoft.com/kb/295305
Christian Buettner-167247
Christian Buettner-167247
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3551 Visits: 3889
Why was this question reposted with the same misleading explanation as the original QOTD a month ago?

Best Regards,

Chris Büttner
Lokesh Vij
Lokesh Vij
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2050 Visits: 1599
sharath.chalamgari (6/24/2013)
http://support.microsoft.com/kb/295305


I never thought about creating a temp table using if/else statements. Seems this is a good way. Thanks for sharing :-)

If that was not a temp table, we can use EXEC ('CREATE TABLE <>....') as well.

~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


Hugo Kornelis
Hugo Kornelis
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10943 Visits: 11983
Good question, and mostly correct explanation. Except for the last sentence.

Such an error breaks the integrity of the code and makes further evaluation impossible. Parsing stops immediately at this point and the DROP statement is never evaluated.

This is not true. Parsing does continue. The reason the DROP TABLE does not generate an error is because of "defered name resolution" - if a table does not exist at parse time, it is still accepted and SQL Server will continue parsing and compiling the batch, making a mental note to retry parsing and compiling the offending statement at execution time. This is in order to support scenario's where a table is created while the code is running (e.g. a permanent table created by a called stored procedure, or by <shudder> dynamic SQL).

One way to check this is to change DROP TABLE to DROP TALE - you will now get a third error message, that TALE is not a supported object type for CREATE, DROP, or ALTER. Another way to see this in action is to execute this batch:
SELECT 1;
DROP TABLE #TableA;


If you run this, you'll get a result set with "1", and an error message - this indicates that the error was only returned after the initial parse and compile; executing the first select; and then the second attempt to parse and compile the DROP statement. Conversely, the batch below will ONLY return an error message, indicating that even the first statement of the batch was not executed because the error was generated during the initial parse and compile:
SELECT 1;
IF 1 = 1
CREATE TABLE #Table (A int);
ELSE
CREATE TABLE #Table (B int);




Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Hugo Kornelis
Hugo Kornelis
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10943 Visits: 11983
sharath.chalamgari (6/24/2013)
what could be the better approach in this kind of situation , is there any better option than this

Rethink your design.

Seriously. SQL is not designed for tables that can contain just about everything. If you start your process with a solid data model, you'll get a solid database design. In that design, each table has a fixed set of columns that will not change at run-time. So in a well designed database, you should not need this kind of nonsense.

The only situations where I have seen this kind of code are:
1. No solid design, or a "design" (and I'm using that word in a very loose sense) that allows end users to add columns at run time. That's not what the relational model is for. Use relational tables for structured data, and if the user has a need for additional unstructrured data, provide them with an XML column for that. There may be other alternatives, to be decided on a case by case basis, but the bottom line is that "normal" tables should be fixed and only change during deployment, and flexible schema should be in its own separate area.
2. Generic purpose stored procedures that do "something" for generic tables. Just don't. How hard can it be to make multiple copies of the stored procedure and adapt them as needed to the specifics of each table? I much rather have twenty-five almost identical stored procedures that are elementary to graps and simple to maintain, than one "generic" stored proc that needs so much control flow to handle all special cases that it will become a maintenance nightmare the minute the original developer moves on.


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search