February 6, 2012 at 9:07 am
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/
February 6, 2012 at 9:25 am
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
February 6, 2012 at 11:50 am
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/
February 6, 2012 at 11:55 am
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
February 6, 2012 at 12:10 pm
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/
July 6, 2013 at 10:46 am
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!
July 8, 2013 at 6:48 am
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
How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
July 8, 2013 at 10:42 pm
This link might be useful:
July 9, 2013 at 8:18 am
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%'''
July 9, 2013 at 9:04 am
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
July 13, 2013 at 12:46 am
Thank you Geeks for this valuable inputs 🙂
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply