Technical Article

Unused Input Parameters

,

I recently came across some code where various input parameters were declared in the creation of a stored procedure though weren't actually being used anywhere in the script. As it turned out, the developer had modified the code at some point, removing these parameters as they were no longer needed for filtering purposes, but forgot to remove them from the input parameter list.

The stored procedure below will scan all relevant objects and return any that have unused input parameters, outputting the following:

  • schema_name: Schema name of the object in which the unused input parameter was found
  • object_name: Object name in which the unused input parameter was found
  • parameter_name: Name of the unused input parameter
  • object_type: Type of object in which the unused input parameter was found (for example: stored procedure, scalar function, etc.)
  • data_type: Data type of the unused input parameter
  • is_output: Indicator specifying whether or not the unused input parameter was defined with the "OUTPUT" clause
  • definition: Definition details of the object in which the unused input parameter was found

To execute the stored procedure simply pass it the name of the database to search against:

EXECUTE dbo.usp_Unused_Input_Parameters
    @Database_Name = N'my_database'

NOTE: Always make sure that no other objects or applications are referencing any input parameters that you decide to remove. For example: if you remove an input parameter from procedure A, but procedure B calls procedure A and passes to it one of the now removed parameters then you will also need to update procedure B's call to procedure A.

Any friendly feedback is always welcome. Enjoy!

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
SET NOCOUNT ON


-----------------------------------------------------------------------------------------------------------------------------
--Error Trapping: Check If Procedure Already Exists And Create Shell If Applicable
-----------------------------------------------------------------------------------------------------------------------------

IF OBJECT_ID (N'dbo.usp_Unused_Input_Parameters', N'P') IS NULL
BEGIN

EXECUTE ('CREATE PROCEDURE dbo.usp_Unused_Input_Parameters AS SELECT 1 AS shell')

END
GO


-----------------------------------------------------------------------------------------------------------------------------
--Stored Procedure Details: Listing Of Standard Details Related To The Stored Procedure
-----------------------------------------------------------------------------------------------------------------------------

--Purpose: Identify All Objects Containing Unused Input Parameters
--Create Date (MM/DD/YYYY): 11/25/2012
--Developer: Sean Smith (s.smith.sql AT gmail DOT com)
--Additional Notes: N/A


-----------------------------------------------------------------------------------------------------------------------------
--Modification History: Listing Of All Modifications Since Original Implementation
-----------------------------------------------------------------------------------------------------------------------------

--Description: No Modifications To Date
--Date (MM/DD/YYYY): N/A
--Developer: N/A
--Additional Notes: N/A


-----------------------------------------------------------------------------------------------------------------------------
--Main Query: Create Procedure
-----------------------------------------------------------------------------------------------------------------------------

ALTER PROCEDURE dbo.usp_Unused_Input_Parameters

@Database_Name AS SYSNAME

AS

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
SET NOCOUNT ON
SET ANSI_WARNINGS OFF
SET ARITHABORT OFF
SET ARITHIGNORE ON
SET TEXTSIZE 2147483647


EXECUTE

(
N'
USE [' + @Database_Name + N']


SELECT
 SCHEMA_NAME (O.[schema_id]) AS [schema_name]
,O.name AS [object_name]
,P.name AS parameter_name
,O.[type] AS object_type
,TYPE_NAME (P.user_type_id) AS data_type
,(CASE P.is_output
WHEN 1 THEN ''Yes''
ELSE ''No''
END) AS is_output
,SQLM.[definition]
FROM
sys.parameters P
INNER JOIN sys.objects O ON O.[object_id] = P.[object_id]
AND O.is_ms_shipped = 0
INNER JOIN sys.sql_modules SQLM ON SQLM.[object_id] = P.[object_id]
LEFT JOIN

(
SELECT
 XP.[object_id]
,XP.parameter_id
,XP.name + NCHAR (13) AS parameter_name_modified
,REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (REPLACE (
XSQLM.[definition] + NCHAR (13)
, XP.name + N'''', XP.name + NCHAR (13))
, XP.name + N'' '', XP.name + NCHAR (13))
, XP.name + N''!'', XP.name + NCHAR (13))
, XP.name + N''"'', XP.name + NCHAR (13))
, XP.name + N''%'', XP.name + NCHAR (13))
, XP.name + N''&'', XP.name + NCHAR (13))
, XP.name + N'''''''', XP.name + NCHAR (13))
, XP.name + N''('', XP.name + NCHAR (13))
, XP.name + N'')'', XP.name + NCHAR (13))
, XP.name + N''*'', XP.name + NCHAR (13))
, XP.name + N''+'', XP.name + NCHAR (13))
, XP.name + N'','', XP.name + NCHAR (13))
, XP.name + N''-'', XP.name + NCHAR (13))
, XP.name + N''.'', XP.name + NCHAR (13))
, XP.name + N''/'', XP.name + NCHAR (13))
, XP.name + N'';'', XP.name + NCHAR (13))
, XP.name + N''<'', XP.name + NCHAR (13))
, XP.name + N''='', XP.name + NCHAR (13))
, XP.name + N''>'', XP.name + NCHAR (13))
, XP.name + N''['', XP.name + NCHAR (13))
, XP.name + N'']'', XP.name + NCHAR (13))
 AS definition_modified
FROM
sys.parameters XP
INNER JOIN sys.sql_modules XSQLM ON XSQLM.[object_id] = XP.[object_id]
WHERE
EXISTS

(
SELECT
*
FROM
sys.parameters YP
WHERE
YP.[object_id] = XP.[object_id]
AND YP.parameter_id <> XP.parameter_id
AND LEFT (YP.name, LEN (XP.name)) = XP.name
)

) FN ON FN.[object_id] = P.[object_id] AND FN.parameter_id = P.parameter_id

CROSS APPLY

(
SELECT
 ISNULL (FN.parameter_name_modified, P.name) AS parameter_name_compare
,ISNULL (FN.definition_modified, SQLM.[definition]) AS definition_compare
) CV

WHERE
P.parameter_id <> 0
AND CHARINDEX (CV.parameter_name_compare, CV.definition_compare, CHARINDEX (CV.parameter_name_compare, CV.definition_compare) + 1) = 0
ORDER BY
 SCHEMA_NAME (O.[schema_id])
,O.name
,P.name
 '
)
GO

Rate

4.95 (20)

You rated this post out of 5. Change rating

Share

Share

Rate

4.95 (20)

You rated this post out of 5. Change rating