Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Temp Table Name confusion with Nested Procedures?


Temp Table Name confusion with Nested Procedures?

Author
Message
mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
Normally I ask this type of question on Ask SSC, but I thought I'd try one here for a change.

I have a procedure that was working fine yesterday, now it breaks. It looks like the engine's getting confused about a temp table name today. If I have a local temp table with the same name, say #MyTemp, in both the calling and called nested procedure, will the engine choke on that? It seems that I've seen this before and had to change one of the names to resolve the issue.

I know that it would be best practice to use different names just in case, but it would seem that SQL could keep that straight rather than getting confused. Also, it was working just fine yesterday.

Thanks for your time!

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
Garadin
Garadin
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1523 Visits: 4107
Temp tables created in the outer SP are available to the Inner SP, so you should definitely avoid this, as creating one with the same name will be confusing... but it doesn't seem to actually error. What's the error you're getting? See below example.

CREATE PROC #B
AS

SELECT * FROM #MyTemp
SELECT 'B' B INTO #MyTemp
SELECT * FROM #MyTemp

SELECT * FROM tempdb.sys.objects WHERE name LIKE '%MyTemp%'
GO

CREATE PROC #A
AS

SELECT 'A' A INTO #MyTemp

EXEC #B
SELECT * FROM #MyTemp
GO

EXEC #A

DROP PROC #B
DROP PROC #A



Seth Phelabaum
Consistency is only a virtue if you're not a screwup. ;-)

Links: How to Post Sample Data :: Running Totals :: Tally Table :: Cross Tabs/Pivots :: String Concatenation
mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
Thank you Garadin, I actually changed the name of the calling procedure's temp table and am still getting the error. So I must have been wrong about that - let me investigate further before I stick my foot in my mouth (again!) here.

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
Garadin
Garadin
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1523 Visits: 4107
I'm just glad I decided to test it before I answered... or I'd have been wrong. Hehe

Seth Phelabaum
Consistency is only a virtue if you're not a screwup. ;-)

Links: How to Post Sample Data :: Running Totals :: Tally Table :: Cross Tabs/Pivots :: String Concatenation
mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
Garadin (7/1/2011)
I'm just glad I decided to test it before I answered... or I'd have been wrong. Hehe


Ha! Don't feel like the Lone Stranger on that one - I have to do that too all too often myself.

Anyway, the error is "Invalid column name 'PGID'." on the called procedure

So if I open the called (or child?) procedure (from the server to be sure it's the compiled program) and run it, no errors. If I call it manually from an exec, it chokes. So it may just be a parameter value snafu.

Parameters are fantastic! And yet, they're such a pain sometimes. w00t

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
OK, now I wish that I could borrow the head-desk avatar from WayneS! Angry

After getting fed up with verifying the parameters and parameter values over and over. I closed the procedure without saving it, opened it back up and it works perfectly. (!) 'Was running perfectly yesterday and I ran it without change this morning, but it balked. Anyway, the answer is a mystery.

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
OK, this procedure and it's nested cousin caused issues again this morning. Here is the odd part, the proc. running through Crystal Reports ran just fine. I open the procedure in SSMS, again straight from the server to be sure it is indeed the code in question) and it errors out.

I changed the name of the temp table that I thouht it was confused about (so that the two procs were not using a temp table with the same name) and it runs fine. So it looks like the SQL Engine can indeed get confused that way. Exclamation Mark

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
WayneS
WayneS
SSCertifiable
SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)

Group: General Forum Members
Points: 6265 Visits: 10404
mtillman-921105 (7/1/2011)
OK, now I wish that I could borrow the head-desk avatar from WayneS! Angry

Feel free to borrow it anytime... it's at http://www.dreamwidth.org/userpic/21008/20791
(Sometimes, I'd like to change my avatar to this one - but I think Steve would ask me to change it.)
[evil grin]Hmm... isn't Steve on vacation right now?[/evil grin]


Anyway, to answer your question: From BOL:CREATE TABLE
A local temporary table created within a stored procedure or trigger can have the same name as a temporary table that was created before the stored procedure or trigger is called. However, if a query references a temporary table and two temporary tables with the same name exist at that time, it is not defined which table the query is resolved against.

(emphasis mine)

Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
Links: For better assistance in answering your questions, How to ask a question, Performance Problems, Common date/time routines,
CROSS-TABS and PIVOT tables Part 1 & Part 2, Using APPLY Part 1 & Part 2, Splitting Delimited Strings

mtillman-921105
mtillman-921105
SSChasing Mays
SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)SSChasing Mays (638 reputation)

Group: General Forum Members
Points: 638 Visits: 3852
WayneS (7/5/2011)
mtillman-921105 (7/1/2011)
OK, now I wish that I could borrow the head-desk avatar from WayneS! Angry

Feel free to borrow it anytime... it's at http://www.dreamwidth.org/userpic/21008/20791
(Sometimes, I'd like to change my avatar to this one - but I think Steve would ask me to change it.)
[evil grin]Hmm... isn't Steve on vacation right now?[/evil grin]


Anyway, to answer your question: From BOL:CREATE TABLE
A local temporary table created within a stored procedure or trigger can have the same name as a temporary table that was created before the stored procedure or trigger is called. However, if a query references a temporary table and two temporary tables with the same name exist at that time, it is not defined which table the query is resolved against.

(emphasis mine)


Thank you Wayne! That explains it. It's a mystery to my why this hasn't happened to me more frequently. But I've learned my lesson and at least there's an explanation.

Hilarious .gif by the way. I'll have to share that one.

______________________________________________________________________
The greatest enemy of knowledge is not ignorance, it is the illusion of knowledge. - Stephen Hawking
tfifield
tfifield
SSC Eights!
SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)SSC Eights! (993 reputation)

Group: General Forum Members
Points: 993 Visits: 2890
I got burned on this the hard way. A temp table was created in a trigger. I used a very simple table name like #T for temp.

I had such a table created in SSMS with the same name I was using for analysis purposes with, of course, a different set of columns.

When I ran an update on the table with the trigger I kept getting the error with invalid column name.

I was very embarrassed when I figured out that the trigger was inheriting the #T table on the same connection. Ooops!
Todd Fifield
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