Many a times we come across a scenario where we need to execute some code based on whether a Stored Procedure exists or not. There are different ways of identifying the Stored Procedure existence in Sql Server, in this article will list out the commonly used approaches. Let me know which approach you use and reason for the same.
To demonstrate these different approaches let us create a sample database with a Table and a Stored Procedure by the below script:
CREATE DATABASE SqlHintsDemoDB GO USE SqlHintsDemoDB GO CREATE TABLE dbo.Customers (CustId INT, Name NVARCHAR(50)) GO CREATE PROCEDURE dbo.GetCustomers(@CustId AS INT) AS BEGIN SELECT * FROM dbo.Customers WHERE CustId = @CustId END GO
[ALSO READ] How to check if a Table exists in Sql Server
Approach 1: Using sys.procedures catalog view
We can write a query like below to check if a GetCustomers Stored Procedure exists in the current database in any schema.
USE SqlHintsDemoDB GO IF EXISTS(SELECT 1 FROM sys.procedures WHERE Name = 'GetCustomers') BEGIN PRINT 'Stored Procedure Exists' END
The above query checks the existence of the GetCustomers Stored Procedure across all the schemas in the current database. Instead of this if you want to check the existence of the Stored Procedure in a specified Schema then we can re-write the above query as below:
USE SqlHintsDemoDB GO IF EXISTS(SELECT 1 FROM sys.procedures WHERE object_id = OBJECT_ID(N'dbo.GetCustomers')) BEGIN PRINT 'Stored Procedure Exists' END
If you want to check the existence of a stored procedure in a database other than the current contextual database, then we can use the script like below:
USE MASTER GO IF EXISTS(SELECT 1 FROM SqlHintsDemoDB.sys.procedures WHERE object_id=OBJECT_ID(N'SqlHintsDemoDB.dbo.GetCustomers')) BEGIN PRINT 'Stored Procedure Exists' END
Note: sys.procedures catalog view contains a row for each object of the below type:
Type | Description |
P | SQL Stored Procedure |
PC | Assembly (CLR) stored-procedure |
RF | Replication-filter-procedure |
X | Extended stored procedure |
If you are looking for only Sql Stored Procedure, then in sys.procedures catalog views query you can add the filter AND condition as: Type = N’P’.
[ALSO READ] How to check if a record exists in table
Approach 2: Using sys.objects catalog view
sys.procedures catalog view inherits the rows from the sys.objects catalog view, sys.objects catalog view is referred to as base view where as sys.procedures is referred to as derived view. sys.procedures will return the rows only for the stored procedures whereas sys.objects view apart from returning the rows for stored procedures, it returns rows for the objects like: tables, views etc.
We can write a script like below to check the existence of a stored procedure in the current contextual database:
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'dbo.GetCustomers') AND type IN ( N'P', N'PC',N'X',N'RF')) BEGIN PRINT 'Stored Procedure Exists' END
If you want check the existence of a stored procedure in a database other than the contextual database then we can re-write the above query by using three part naming convention as shown below:
USE master GO IF EXISTS (SELECT * FROM SqlHintsDemoDB.sys.objects WHERE object_id=OBJECT_ID(N'SqlHintsDemoDB.dbo.GetCustomers') AND type IN ( N'P', N'PC',N'X',N'RF')) BEGIN PRINT 'Stored Procedure Exists' END
[ALSO READ] How to check if a Temp table exists
Approach 3: Using sys.sql_modules Catalog View
We can use the sys.sql_modules catalog view to check the existence of the Stored Procedure as shown below:
USE SqlHintsDemoDB GO IF EXISTS (SELECT 1 FROM sys.sql_modules WHERE object_id = OBJECT_ID(N'dbo.GetCustomers') AND OBJECTPROPERTY(object_id, N'IsProcedure') = 1) BEGIN PRINT 'Stored Procedure Exists' END
[ALSO READ] How to check if a Database exists
Approach 4: Using OBJECT_ID() function
We can use OBJECT_ID() function like below to check if a GetCustomers Stored procedure exists in the current database.
USE SqlHintsDemoDB GO IF OBJECT_ID(N'dbo.GetCustomers', N'P') IS NOT NULL BEGIN PRINT 'Stored Procedure Exists' END
Specifying the Database Name and Schema Name parts for the Stored Procedure Name is optional. But specifying Database Name and Schema Name provides an option to check the existence of the stored procedure in the specified database and within a specified schema, instead of checking in the current database across all the schemas. The below query shows that, even though the current database is MASTER database, we can check the existence of the GetCustomers stored procedure in the dbo schema in the SqlHintsDemoDB database.
USE MASTER GO IF OBJECT_ID(N'SqlHintsDemoDB.dbo.GetCustomers', N'P') IS NOT NULL BEGIN PRINT 'Stored Procedure Exists' END
[ALSO READ] How to check if a View exists
Approach 5: Using INFORMATION_SCHEMA.ROUTINES View
We can use the INFORMATION_SCHEMA.ROUTINES view to check the existence of the stored procedure as shown below:
USE SqlHintsDemoDB GO IF EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'GetCustomers' AND ROUTINE_TYPE = 'PROCEDURE') BEGIN PRINT 'Stored Procedure Exists' END
Approach 6: Avoid Using sys.sysobjects System table
We should avoid using sys.sysobjects System Table directly, direct access to it will be deprecated in some future versions of the Sql Server. As per Microsoft BOL link, Microsoft is suggesting to use the catalog views sys.objects/sys.procedures/sys.sql_modules instead of sys.sysobjects system table directly to check the existence of the stored procedure.
USE SqlHintsDemoDB GO IF EXISTS(SELECT 1 FROM sys.sysobjects WHERE id = OBJECT_ID(N'dbo.GetCustomers') AND xtype=N'P' ) BEGIN PRINT 'Stored Procedure Exists' END
[ALSO READ] :
How to check if a Database exists
How to check if a Table exists
How to check if a View exists
How to check if Temp table exists
How to check if a record exists in table