January 25, 2018 at 6:56 am
Dear all,
I have a drop statement related with a temp table that works properly when called from inside an SP but does not drop anything when callen from inside the query pane (whiout being inside an SP.
Example:
DECLARE @DB VARCHAR(500)
DECLARE @STRSQL VARCHAR(1000)
IF EXISTS (SELECT * FROM SYS.OBJECTS WHERE NAME ='#ReturnDBNames')
BEGIN
DROP TABLE #ReturnDBNames
END
CREATE TABLE #ReturnDBNames
(
Name VARCHAR(200)
)
DECLARE UserDBs CURSOR FOR
SELECT
[d].[name]
FROM
[sys].[databases] AS [d]
WHERE
[d].database_id > 4
ORDER BY
[d].[name]
The DROP, only drops the table if called from inside a SP, can you help me understand why? thank you.
January 25, 2018 at 7:04 am
DECLARE @DB VARCHAR(500)
DECLARE @STRSQL VARCHAR(1000)
-- IF EXISTS (SELECT * FROM SYS.OBJECTS WHERE NAME ='#ReturnDBNames')
--BEGIN
-- DROP TABLE #ReturnDBNames
--END
IF OBJECT_ID('tempdb..#ReturnDBNames') IS NOT NULL DROP TABLE #ReturnDBNames;
CREATE TABLE #ReturnDBNames (
[Name] VARCHAR(200)
)
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
January 25, 2018 at 7:24 am
As you're in 2016, you can use DIE syntax:
DROP TABLE IF EXISTS #ReturnDBNames
The absence of evidence is not evidence of absence
- Martin Rees
The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
- Phil Parkin
January 25, 2018 at 7:46 am
ChrisM@Work - Thursday, January 25, 2018 7:04 AMNot really - the temp table will be dropped when the stored procedure completes, because this isn't the correct code for identifying whether or not a temp table exists.DECLARE @DB VARCHAR(500)
DECLARE @STRSQL VARCHAR(1000)
-- IF EXISTS (SELECT * FROM SYS.OBJECTS WHERE NAME ='#ReturnDBNames')
--BEGIN
-- DROP TABLE #ReturnDBNames
--END
IF OBJECT_ID('tempdb..#ReturnDBNames') IS NOT NULL DROP TABLE #ReturnDBNames;
CREATE TABLE #ReturnDBNames (
[Name] VARCHAR(200)
)
๐ Ok. So in this case is working just because when the SP is droped all its temporary tables will also be droped because the session as ended, is that it?
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply