Every now and again you see articles and posts about putting sp_ at the beginning of a stored procedure. So what does that do and why should we care? The primary effect is that if you put a stored procedure starting with sp_ in master you can call it directly from any database.
USE master; GO CREATE PROCEDURE sp_Test AS PRINT 'This SP is run from the master DB'; GO USE Test; GO EXEC sp_Test; GO
This SP is run from the master DB
Well that is fairly useful. Of course you could have easily called it using master.dbo.sp_Test too. So what happens if we already have an sp_Test stored procedure in the original database?
USE Test; GO CREATE PROCEDURE sp_Test AS PRINT 'This SP is run from the Test DB'; GO EXEC sp_Test; GO
This SP is run from the Test DB
Simple enough. It will call the version of the SP from the current database rather than the version in master.
Now here is another interesting test with maybe a bit less obvious result.
USE Test; GO DROP PROCEDURE sp_Test; GO USE master; GO ALTER PROCEDURE sp_Test AS SELECT DB_NAME(); SELECT * FROM sys.sysfiles; GO USE Test; GO EXEC sp_Test; GO
Isn’t that interesting? The GUI shows our current context as Test, DB_NAME shows our current context as Test but when querying a database specific system view it’s clearly looking at the version out of master. So what does that mean for us? If you plan on creating an SP like this that needs to use system views you will need to take this into account. One of the easiest ways to handle this is going to be dynamic SQL, by either generating code with a USE before the beginning of the query or by generating a three part name for each of the system tables/views you plan on querying.
Filed under: Microsoft SQL Server, SQLServerPedia Syndication, System Databases, System Functions and Stored Procedures, T-SQL Tagged: code language, language sql, microsoft sql server, system databases, system functions, T-SQL