Each session should be able to have its own temp table, but there can be problems.

1

May 10, 2018 by Kenneth Fisher

You should be able to create a #temp in every session. That’s the idea, right? It’s one of the things that differentiates a global temp table from a local temp table. But there can be some difficulties with that.

If you are working with reusable code that uses temp tables (a stored procedure for example), sometimes you need to create a constraint. The thing about constraints is that their names are just as unique as tables, stored procedures etc. i.e. the name of a constraint can only be used once. You can’t have two tables with the same constraint name. In fact, you can’t even have a constraint name that matches a table, stored procedure etc name.

Per BOL

constraint_name
Is the name of a constraint. Constraint names must be unique within the schema to which the table belongs.

The reason is simple enough. Constraint names are stored in sys.objects. Just like tables, stored procedures etc and there is a unique constraint on that name. Well, technically name and schema_id I guess.

So that said, when you create a constraint on a temp table you run into the same problem. The names are stored in tempdb but still have to be unique within tempdb. So if you do this:

CREATE TABLE #Temp (
	col1 int CONSTRAINT pk_#Temp PRIMARY KEY)

Then you are only going to be able to have one copy of #temp at a time, even though it’s a local temp table and you are working in a different session. Technically the problem is that you can only have one copy of pk_#Temp and the error you will get is:

Msg 2714, Level 16, State 5, Line 1
There is already an object named ‘pk_#Temp’ in the database.
Msg 1750, Level 16, State 1, Line 1
Could not create constraint or index. See previous errors.

I mentioned a while back that you should avoid the default names for constraints. This is one case where you absolutely should not. Always take the default name for a constraint within a temp table. That will keep it unique.

CREATE TABLE #Temp (
	col1 int PRIMARY KEY)

Note: This is for all types of constraints, I only used PRIMARY KEY because it was convenient and probably one of the more common ones used in situations like this.

One thought on “Each session should be able to have its own temp table, but there can be problems.

  1. […] Kenneth Fisher argues that you should use default naming for temp table constraints: […]

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Google+ photo

You are commenting using your Google+ account. Log Out /  Change )

Twitter picture

You are commenting using your Twitter account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Enter your email address to follow this blog and receive notifications of new posts by email.

Join 2,469 other followers

Follow me on Twitter

ToadWorld Pro of the Month November 2013
%d bloggers like this: