January 4, 2008 at 7:33 pm
2 different questions:
1. Can someone jot down the statements to check if a particular temporary table exists or not?
2. And what is the recommended way to check if an ordinary user created table exists or not...is the below recommended:
if exists (select * from sysobjects where name = 'mytesttable')
print 'exists';
else
print 'does not exist';
January 4, 2008 at 8:31 pm
Don't use sysobjects, use information_schema.tables.
January 4, 2008 at 8:38 pm
Don't use either... use the functions built for this...
1. Check if temp table exists...
IF OBJECT_ID('TempDB..#temptablename','U') IS NOT NULL
PRINT 'Table Exists'
ELSE
PRINT 'Table Not Exists'
2. Same for permanent tables...
IF OBJECT_ID('dbo.permanenttablename','U') IS NOT NULL
PRINT 'Table Exists'
ELSE
PRINT 'Table Not Exists'
--Jeff Moden
Change is inevitable... Change for the better is not.
January 7, 2008 at 12:24 am
Concur...
2. Same for permanent tables...
IF OBJECT_ID('dbo.permanenttablename','U') IS NOT NULL PRINT 'Table Exists' ELSE PRINT 'Table Not Exists'
IF OBJECT_ID(' .dbo.permanenttablename','U') IS NOT NULL PRINT 'Table Exists' ELSE PRINT 'Table Not Exists'
Always include the DB name wherever it is necessary.Because it should reduce the unwanted confusions.
Otherwise Jeff Query looks fine.
karthik
January 7, 2008 at 12:26 am
My proof read statement is,
IF OBJECT_ID('DBname.dbo.permanenttablename','U') IS NOT NULL PRINT 'Table Exists' ELSE PRINT 'Table Not Exists'
karthik
January 7, 2008 at 5:21 am
In the documentation object_id should return an integer if it finds the table object. But if I do something like
if (object_id('tempdb..#tblTemp','u') > 0)
print 'exists'
else
print 'not exists'
...its not compiling...:ermm:
January 7, 2008 at 5:24 am
karthikeyan (1/7/2008)
Concur...2. Same for permanent tables...
IF OBJECT_ID('dbo.permanenttablename','U') IS NOT NULL PRINT 'Table Exists' ELSE PRINT 'Table Not Exists'
IF OBJECT_ID(' .dbo.permanenttablename','U') IS NOT NULL PRINT 'Table Exists' ELSE PRINT 'Table Not Exists'
Always include the DB name wherever it is necessary.Because it should reduce the unwanted confusions.
Otherwise Jeff Query looks fine.
No... I disagree... 3 part naming convention is not necessary unless you are querying outside the current database.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 7, 2008 at 5:34 am
Arun T Jayapal (1/7/2008)
if (object_id('tempdb..#tblTemp','u') > 0)
print 'exists'
else
print 'not exists'
...its not compiling...:ermm:
Looks fine, and runs fine for me. What's the error that you're getting?
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 7, 2008 at 1:33 pm
Steve,
I always use SYSOBJECT but you suggested to use information_schema.tables. What's wrong with using SYSOBJECT?
Maybe I really need to beef up my DBA skills, I guess being a part time DBA still require a full time DBA knowledge.
January 7, 2008 at 2:14 pm
Arun T Jayapal (1/7/2008)
In the documentation object_id should return an integer if it finds the table object. But if I do something like
if (object_id('tempdb..#tblTemp','u') > 0)
print 'exists'
else
print 'not exists'
...its not compiling...:ermm:
1st.
Must be a copy-paste problem.
Check what you've got in your QA after copying the code.
See if sign ">" is transferred correctly.
2nd.
Your condition is wrong.
Object_ID can be negative.
It must be:
[Code]
IF object_id('tempdb..#tblTemp','u') IS NOT NULL
print 'exists'
else
print 'not exists'
[/Code]
_____________
Code for TallyGenerator
January 7, 2008 at 2:16 pm
Loner (1/7/2008)
Steve,I always use SYSOBJECT but you suggested to use information_schema.tables. What's wrong with using SYSOBJECT?
Maybe I really need to beef up my DBA skills, I guess being a part time DBA still require a full time DBA knowledge.
It's not a good idea to give every user rights to access system tables.
Even for reading only.
It's just one reason.
_____________
Code for TallyGenerator
January 7, 2008 at 3:57 pm
Jeff Moden (1/4/2008)
Don't use either... use the functions built for this...1. Check if temp table exists...
IF OBJECT_ID('TempDB..#temptablename','U') IS NOT NULL
PRINT 'Table Exists'
ELSE
PRINT 'Table Not Exists'
2. Same for permanent tables...
IF OBJECT_ID('dbo.permanenttablename','U') IS NOT NULL
PRINT 'Table Exists'
ELSE
PRINT 'Table Not Exists'
Your checks are not valid for SQL 7.0 and 2000. (This is the SQL Server 7,2000 T-SQL forum)
The following work in SQL 7.0, 2000, and 2005.
-- Check for temp table
if exists (
select *
from
tempdb.dbo.sysobjects o
where
o.xtype in ('U')and
o.id = object_id( N'tempdb..#temptablename')
)
begin
print 'Table exists'
end
else
begin
print 'Table does not exist'
end
-- Check for user table in current database
if objectproperty(object_id('authors'),'IsUserTable') = 1
begin
print 'Table exists'
end
else
begin
print 'Table does not exist'
end
January 7, 2008 at 5:15 pm
Michael Valentine Jones (1/7/2008)
Your checks are not valid for SQL 7.0 and 2000. (This is the SQL Server 7,2000 T-SQL forum)
It's because undocumented parameter Jeff used.
Follow BOL prescriptions an you're OK:
[Code]IF OBJECT_ID('dbo.permanenttablename') IS NOT NULL
...
[/Code]
Parameter helps to understand if the object is a table or anything else.
But problem is if you have a view dbo.SomeName you cannot create a table dbo.SomeName anyway.
So, though that parameter could be useful in some cases I would not suggest to use it extensively. At least you need to understand what do you miss there.
_____________
Code for TallyGenerator
January 7, 2008 at 5:22 pm
Michael Valentine Jones (1/7/2008)
Your checks are not valid for SQL 7.0 and 2000. (This is the SQL Server 7,2000 T-SQL forum)
Maybe not in SQL Server 7 because of the undocumented parameter I used (like Sergiy said)... but even with the extra parameter, the code works fine in 2k and 2k5 (or, at least it does on my servers).
--Jeff Moden
Change is inevitable... Change for the better is not.
January 7, 2008 at 5:26 pm
Sergiy (1/7/2008)
Michael Valentine Jones (1/7/2008)
Your checks are not valid for SQL 7.0 and 2000. (This is the SQL Server 7,2000 T-SQL forum)It's because undocumented parameter Jeff used.
Follow BOL prescriptions an you're OK:
[Code]IF OBJECT_ID('dbo.permanenttablename') IS NOT NULL
...
[/Code]
Parameter helps to understand if the object is a table or anything else.
But problem is if you have a view dbo.SomeName you cannot create a table dbo.SomeName anyway.
So, though that parameter could be useful in some cases I would not suggest to use it extensively. At least you need to understand what do you miss there.
The parameter that Jeff used is not undocumented. It was introduced in SQL 2005 and is documented in the SQL 2005 BOL. That is why I said the checks are not valid for SQL 7.0 and 2000.
The problem with "IF OBJECT_ID('dbo.permanenttablename') IS NOT NULL" is that it cannot tell if the object is a table or some other kind of object. The code from my first post returns true only if they are actually tables.
Viewing 15 posts - 1 through 15 (of 48 total)
You must be logged in to reply to this topic. Login to reply