Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations IamaSherpa on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Getting table names from sysobjects 1

Status
Not open for further replies.

developer155

Programmer
Jan 21, 2004
512
US
How can I get a list of all tables in the db in the following format?

servername.dbname.dbo.tablename

so far I have
select name from sysobjects where type='U'

that returns only names of tables os i need servername and dbname

thanks!
 
There is no central table which has a list of all the tables in every database on the server. You need to query the sysobjects table in each database to get the information.

This code will do the trick.
Code:
create table #tables
(database_name sysname,
owner sysname,
table_name sysname)

exec sp_MSforeachdb 'use ?
insert into #tables
select db_name(), sysusers.name, sysobjects.name
from sysobjects
join sysusers on sysobjects.uid = sysusers.uid
where sysobjects.xtype = ''U'''

select @@SERVERNAME + '.' + database_name + '.' + owner + '.' + table_name
from #tables

drop table #tables

Denny
MCSA (2003) / MCDBA (SQL 2000)
MCTS (SQL 2005 / Microsoft Windows SharePoint Services 3.0: Configuration / Microsoft Office SharePoint Server 2007: Configuration)
MCITP Database Administrator (SQL 2005) / Database Developer (SQL 2005)

--Anything is possible. All it takes is a little research. (Me)
[noevil]
 
this is awesome! What do I need to do to only get table on 1 database (the db on which this is run?)

thanks
 
To get the tables from a single database.
Code:
select @@SERVERNAME + '.' + db_name() + '.' + sysusers.name + '.' + sysobjects.name
from sysobjects
join sysusers on sysobjects.uid = sysusers.uid
where sysobjects.xtype = 'U'

You can run the above code from any database. The sp_MSforeachdb procedure uses a cursor to get data from every database.

Denny
MCSA (2003) / MCDBA (SQL 2000)
MCTS (SQL 2005 / Microsoft Windows SharePoint Services 3.0: Configuration / Microsoft Office SharePoint Server 2007: Configuration)
MCITP Database Administrator (SQL 2005) / Database Developer (SQL 2005)

--Anything is possible. All it takes is a little research. (Me)
[noevil]
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top