SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Search Columns in all Databases


Search Columns in all Databases

Author
Message
Welsh Corgi
Welsh Corgi
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25346 Visits: 4895
I'm using the SQL Statement listed below to search the current database for column names.

What I need is a Statement to search all Databases.

Can I use Exec sp_MSforeachdb and if so what is the syntax to include the Database Name?


SELECT obj.Name AS TableName,col.Name AS ColumnName, col.xtype, col.length
FROM Sysobjects AS obj
INNER JOIN syscolumns AS col ON obj.id = col.id
WHERE Obj.xtype = 'U'
AND col.name LIKE '%Salvage%'



For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Sean Lange
Sean Lange
SSC Guru
SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)

Group: General Forum Members
Points: 59332 Visits: 17947
Not exactly sure what you are asking. Are you trying to find all columns in all databases in a single result set?

Something like this should work for you.


create table #Cols
(
TableName nvarchar(128),
Columnname varchar(128),
xtype tinyint,
length int
)



EXECUTE master.sys.sp_MSforeachdb 'USE [?]; insert #Cols SELECT obj.Name AS TableName,col.Name AS ColumnName, col.xtype, col.length
FROM Sysobjects AS obj
INNER JOIN syscolumns AS col ON obj.id = col.id
WHERE Obj.xtype = ''U''
AND col.name LIKE ''%Salvage%'''

select * from #Cols

drop table #Cols



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Welsh Corgi
Welsh Corgi
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25346 Visits: 4895
Thanks Sean.


What function do I user on the parent_object to get the Database Name?

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Sean Lange
Sean Lange
SSC Guru
SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)SSC Guru (59K reputation)

Group: General Forum Members
Points: 59332 Visits: 17947
This what you mean?


create table #Cols
(
DataBaseName varchar(128),
TableName nvarchar(128),
Columnname varchar(128),
xtype tinyint,
length int
)

EXECUTE master.sys.sp_MSforeachdb 'USE [?]; insert #Cols SELECT DB_NAME(), obj.Name AS TableName,col.Name AS ColumnName, col.xtype, col.length
FROM Sysobjects AS obj
INNER JOIN syscolumns AS col ON obj.id = col.id
WHERE Obj.xtype = ''U''
AND col.name LIKE ''%Salvage%'''

select * from #Cols

drop table #Cols



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Welsh Corgi
Welsh Corgi
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25346 Visits: 4895
Yes, that is what I wanted.

Thanks.

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
shy.n86
shy.n86
SSC-Enthusiastic
SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)

Group: General Forum Members
Points: 108 Visits: 45
Hi Geeks,

I have question about usage of this SP that how legal it is use to use this sp?
what kind of impact it does on your sever when a statement with this sp is fired? I mean does it have any negative impacts on using this SP, since it comes under undocumented SPs.

Thank you!
Kingston Dhasian
Kingston Dhasian
SSCertifiable
SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)

Group: General Forum Members
Points: 5832 Visits: 5279
shy.n86 (7/6/2013)
Hi Geeks,

I have question about usage of this SP that how legal it is use to use this sp?
what kind of impact it does on your sever when a statement with this sp is fired? I mean does it have any negative impacts on using this SP, since it comes under undocumented SPs.

Thank you!


I don't think that using this SP is "illegal"
It would not be advisable to use such SP's in Production code, but for ad-hoc requests I don't see any harm using this procedure
You can check the code of the procedure under master->Programmability->Stored Procedures->System Stored Procedures->sp_MSforeachdb


Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Steven Willis
Steven Willis
SSCommitted
SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)

Group: General Forum Members
Points: 1903 Visits: 1721
This link might be useful:

sql-server-integrity-check
sqldriver
sqldriver
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2084 Visits: 2536
I just used this yesterday, if you're ever in the market for a quick select:


sp_MSForEachDB @command1='USE ?;
SELECT
Table_Catalog
,Table_Schema
,Table_Name
,Column_Name
,Data_Type
,Character_Maximum_Length
FROM INFORMATION_SCHEMA.COLUMNS
WHERE DATA_TYPE = ''NVARCHAR'' and COLUMN_NAME like ''Recall%'' and TABLE_NAME LIKE ''%SAMPLE%'''


Elliott Whitlow
Elliott Whitlow
SSC-Insane
SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)

Group: General Forum Members
Points: 22734 Visits: 5314
shy.n86 (7/6/2013)
Hi Geeks,

I have question about usage of this SP that how legal it is use to use this sp?
what kind of impact it does on your sever when a statement with this sp is fired? I mean does it have any negative impacts on using this SP, since it comes under undocumented SPs.

Thank you!
There are no legal implications for you to use it, it is an undocumented stored procedure, which basically means we built it for our use and we don't want to support it for YOURS. So if you use it and it stops working the way you want or it previously had then TOUGH. The only thing even remotely legal about it comes down to you can't complain and have no legal position if you use it and it stops working for you.

As far as performance it is pretty marginal, considering what it is doing.. The statement YOU pass in to execute is much more likely to have a performance impact than it itself.

CEWII
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