Overview
The real power of stored procedures is the ability to pass parameters and have the stored procedure handle the differing requests that are made. In this topic we will look at passing parameter values to a stored procedure.
Explanation
Just like you have the ability to use parameters with your SQL code you can also setup your stored procedures to accept one or more parameter values. All examples use the AdventureWorks database.
Creating a SQL Stored Procedure with Parameters
- To create a stored procedure with parameters using the following syntax:
- CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30) AS
- See details and examples below
SQL Server Query to Turn into a Stored Procedure
Below is the query we want to use to create the stored procedure.
USE AdventureWorks
GO
SELECT *
FROM Person.Address
GO
The idea is to create the stored procedure where the City is passed into the stored procedure so it can create dynamic results. This can be done as follows using a variable. If we run the below code it will return just the results for New York.
USE AdventureWorks
GO
DECLARE @City nvarchar(30)
SET @City = 'New York'
SELECT *
FROM Person.Address
WHERE City = @City
GO
We could use this approach and keep updating the @City variable, but there is a better way to do this by creating a stored procedure.
Create SQL Server Stored Procedure with One Parameter
In this example we will query the Person.Address table from the AdventureWorks database, but instead of getting back all records we will limit it to just a particular city. This example assumes there will be an exact match on the City value that is passed.
USE AdventureWorks
GO
CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30)
AS
SELECT *
FROM Person.Address
WHERE City = @City
GO
To call this stored procedure we would execute it as follows:
EXEC dbo.uspGetAddress @City = 'New York'
Deleting the Stored Procedure
If you created the stored procedure and you want to recreate the stored procedure with the same name, you can delete it using the following before trying to create it again.
USE AdventureWorks
GO
DROP PROCEDURE dbo.uspGetAddress
GO
If you try to create the stored procedure and it already exists you will get an error message.
Msg 2714, Level 16, State 3, Procedure uspGetAddress, Line 1 [Batch Start Line 33]
There is already an object named 'uspGetAddress' in the database.
SQL Server Stored Procedure with Parameter using Wildcard
We can also do the same thing, but allow the users to give us a starting point to search the data.
Here we can change the “=” to a LIKE and use the “%” wildcard.
USE AdventureWorks
GO
CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30)
AS
SELECT *
FROM Person.Address
WHERE City LIKE @City + '%'
GO
This can be run as follows to find all Cities that start with New.
EXEC dbo.uspGetAddress @City = 'New'
SQL Server Stored Procedure Error When Parameter Not Passed
In both of the proceeding examples it assumes that a parameter value will always be passed. If you try to execute the procedure without passing a parameter value you will get an error message such as the following:
EXEC dbo.uspGetAddress
Msg 201, Level 16, State 4, Procedure uspGetAddress, Line 0
Procedure or function 'uspGetAddress' expects parameter '@City', which was not supplied.
SQL Server Stored Procedure using NULL as Default Parameter
In most cases it is always a good practice to pass in all parameter values, but sometimes it is not possible. So in this example we use the NULL option to allow you to not pass in a parameter value. If we create and run this stored procedure as is it will not return any data, because it is looking for any City values that equal NULL.
USE AdventureWorks
GO
CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30) = NULL
AS
SELECT *
FROM Person.Address
WHERE City = @City
GO
If we run the following it will work, but no data will be returned.
EXEC dbo.uspGetAddress
We could change this stored procedure and use the ISNULL function to get around this. So if a value is passed it will use the value to narrow the result set and if a value is not passed it will return all records. (Note: if the City column has NULL values this will not include these values. You will have to add additional logic for City IS NULL).
USE AdventureWorks
GO
CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30) = NULL
AS
SELECT *
FROM Person.Address
WHERE City = ISNULL(@City,City)
GO
Now if we run the below command, all data will be returned from the table.
EXEC dbo.uspGetAddress
Create SQL Server Stored Procedure with Multiple Parameters
Setting up multiple parameters is very easy to do. You just need to list each parameter and the data type separated by a comma as shown below.
USE AdventureWorks
GO
CREATE PROCEDURE dbo.uspGetAddress @City nvarchar(30) = NULL, @AddressLine1 nvarchar(60) = NULL
AS
SELECT *
FROM Person.Address
WHERE City = ISNULL(@City,City)
AND AddressLine1 LIKE '%' + ISNULL(@AddressLine1 ,AddressLine1) + '%'
GO
To execute this you could do any of the following:
-- return rows where City equals Calgary
EXEC dbo.uspGetAddress @City = 'Calgary'
-- return rows where City equals Calgary and AddresLine1 contains A
EXEC dbo.uspGetAddress @City = 'Calgary', @AddressLine1 = 'A'
-- return rows where AddresLine1 contains Acardia
EXEC dbo.uspGetAddress @AddressLine1 = 'Acardia'
-- this will return all rows
EXEC dbo.uspGetAddress
Create or Alter SQL Server Stored Procedure
In SQL Server 2016 and later there is the ability to either CREATE a new stored procedure if it does not already exist or ALTER the procedure if it does exist. Below is a sample of the syntax to make an update to the stored procedure where we only want to return a few columns instead of all columns.
USE AdventureWorks
GO
CREATE OR ALTER PROCEDURE dbo.uspGetAddress @City nvarchar(30) = NULL, @AddressLine1 nvarchar(60) = NULL
AS
SELECT AddressLine1, AddressLine2, City, PostalCode
FROM Person.Address
WHERE City = ISNULL(@City,City)
AND AddressLine1 LIKE '%' + ISNULL(@AddressLine1 ,AddressLine1) + '%'
GO