Script to find the list of stored procedures in all databases
You have to iterate through all databases to do that. If you're adventurous enough, you could use the undocumented stored procedure sp_MSForEachDB, which is buggy and unreliable.
Another possibility is using one of its replacements: Aaron Bertrand's or my humble attempt.
Yet another possibility is using a cursor to loop through all databases:
USE master;
DECLARE @name sysname;
DECLARE @sql nvarchar(max) = '
SELECT
DB_NAME() AS [database_name],
OBJECT_SCHEMA_NAME(object_id) AS [schema_name],
name AS [procedure_name]
FROM sys.procedures
';
DECLARE @theSQL nvarchar(max);
DECLARE @results TABLE (
[database_name] sysname,
[schema_name] sysname,
[procedure_name] sysname
);
DECLARE dbs CURSOR STATIC LOCAL FORWARD_ONLY READ_ONLY
FOR
SELECT name
FROM sys.databases;
-- you may want to exclude system databases here
-- WHERE name NOT IN ('master', 'model', 'msdb', 'tempdb', 'distribution')
OPEN dbs;
FETCH NEXT FROM dbs INTO @name;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @theSQL = 'EXEC ' + QUOTENAME(@name) + '.sys.sp_executesql @sql';
INSERT @results
EXEC sys.sp_executesql @theSQL, N'@sql nvarchar(max)', @sql
FETCH NEXT FROM dbs INTO @name;
END
CLOSE dbs;
DEALLOCATE dbs;
SELECT *
FROM @results;
You can use the following:
CREATE TABLE #SPs (db_name varchar(100), name varchar(100), object_id int)
EXEC sp_msforeachdb 'USE [?]; INSERT INTO #SPs select ''?'', name, object_id from sys.procedures'
SELECT * FROM #SPs
The code above runs a USE
and then a SELECT from sys.procedures
for each database, loading the data into a temp table. sys.procedures
lists out all of the stored procedures in the database and sp_msforeachdb
will run the code on each database (use a ? for the databasename in the code). Once the code is run you can query the temp table to get the consolidated list.
sp_msforeachdb
is known to have issues so you may want to use Aaron Bertrand's improved version located here.