Technical Article

Find dependencies between field and sp/function

,

I would like to share my experience on how to find out dependencies between a table's field name and stored procedures or functions.

I often encounter situations that require database schema changes to meet business requirement changes. For example, changing the name for some fields. It might be an easy thing if the database is small and not used for a complex front-end. However, in my cases, changing a field's name often means:

  1. table schema change
  2. stored procedures change
  3. functions change
  4. data access layer code change
  5. data presentation layer code change

At least the first three are in the SQL scope, and it would be time consuming if we have to open each stored procedure or function and search from there.

This script is not complicated but rather a handy tool. It will list all the stored procedures and functions that contains the given keyword passed as a parameter, and will further indicate if the keyword is actually used as a parameter. This is important because it helps me to find out what functions are related to it in my data access layer code.

There are some limitations:

  1. All my stored procedures start with sp or dd, so you should modify the script to meet your own situation.
  2. All my stored procedures are no longer than 3000 characters, so if you have a longer one, please increase the parameter in the script.
  3. Keyword length is set to varchar(20). You can increase it by modifying the script if you want to search for a longer keyword.
CREATE proc [dbo].[spListDependencies] (@term varchar(20))
AS

declare @name varchar(100)
declare @type varchar(2)
declare @para bit

declare @result varchar(3000)

    create table #t
    (
        ID int identity (1,1),
        [Name] varchar(100),
        [Type] varchar(2),
        Para bit
    )

    declare c cursor for
        SELECT name, 'sp'
        FROM sys.procedures
        where [name] like 'sp%' or [name] like 'dd%'
            UNION
        SELECT name, 'fn'
        FROM sys.objects
        WHERE type_desc LIKE '%FUNCTION%' order by [name]
        
    OPEN c
    FETCH NEXT FROM c
    INTO @name, @type
    
    WHILE @@FETCH_STATUS = 0
    BEGIN
        set @para = 0
        select @result = ROUTINE_DEFINITION
        from information_schema.routines
        where specific_schema = 'dbo'             -- e.g., dbo
          and specific_name   = @name
          
        if CHARINDEX(@term, @result) > 0
        BEGIN
            if CHARINDEX('@' + @term, @result) > 0
                Set @para = 1
            insert into #t (Name, Type, Para) values (@name, @type, @para)
        END

      FETCH NEXT FROM c
        INTO @name, @type
        
    END
    CLOSE c
    DEALLOCATE c
    
    Select * From #t
    Drop table #t

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating