Results 1 to 10 of 10
  1. #1
    Join Date
    Jun 2004
    Location
    Long Island
    Posts
    696

    Unanswered: Check for Invalid stored procedures

    Does anyone know of any code out there to check to see if stored procedures, views, etc. are invalidated (as with Oracle that shows procedure as being INVALID) due to dependent object changes ?

    Danke.

  2. #2
    Join Date
    Jun 2003
    Location
    Ohio
    Posts
    12,592
    Provided Answers: 1
    This will recompile the code in your database and alert you to coding errors. Note that it will not detect errors in dynamic sql, and neither will it detect errors due to a dependent object being deleted, because SQL Server will happily compile such code in the expectation that the object will be there when it is called.
    Requires SQL Server version 2005 or better. Run it on a restored copy of your database rather than your production copy!
    Code:
    ------------------------------------------------------------------------------------------------------------------------
    DESCRIPTION:	Recompiles all the code objects in a database.
    ------------------------------------------------------------------------------------------------------------------------
    REVISION HISTORY:
    EDITOR			DATE		REVISIONS
    blindman		08/2007		Script created.
    blindman		11/19/2008		Modified to handle different schemas.
    ------------------------------------------------------------------------------------------------------------------------
    */
    begin
    
    set nocount on
    create table #SQLStrings (StringID bigint identity(1, 1), SQLString varchar(max))
    create table #CompileErrors (ErrorMessage varchar(4000))
    declare	@SQLString varchar(max)
    declare	@ObjectName varchar(500)
    declare	@ObjectType varchar(10)
    
    declare CodeObjectList cursor for
        select	[schemas].[name] + '.' + [objects].[name], [objects].[type]
        from	sys.objects objects
    			inner join sys.schemas schemas on objects.schema_id = schemas.schema_id
        where	type in ('P', 'TR', 'V', 'TF', 'FN', 'IF')
    			and objects.name <> 'RecompileSQLCode'
        order by parent_object_id
    
    open CodeObjectList
    fetch next from CodeObjectList into @ObjectName, @ObjectType
    while @@fetch_status = 0
        begin
        truncate table #SQLStrings
        insert into #SQLStrings exec sp_helptext @ObjectName
        set @SQLString = ''
        select  @SQLString = @SQLString + ltrim(SQLString) from #SQLStrings order by StringID
    
        set	@SQLString = left(@SQLString, charindex('CREATE ', @SQLString)-1) + 'ALTER ' + right(@SQLString, len(@SQLString)-charindex('CREATE ', @SQLString) -6)
    
        begin try
    	exec (@SQLString)
        end try
        begin catch
    	insert into #CompileErrors (ErrorMessage) values (@ObjectName + ' (' + rtrim(@ObjectType) + '): ' + error_message())
        end catch
        fetch next from CodeObjectList into @ObjectName, @ObjectType
        end
    
    close CodeObjectList
    deallocate CodeObjectList
    
    select * from #CompileErrors
    
    drop table #SQLStrings
    drop table #CompileErrors
    
    end
    If it's not practically useful, then it's practically useless.

    blindman
    www.chess.com: "sqlblindman"
    www.LobsterShot.blogspot.com

  3. #3
    Join Date
    Jun 2004
    Location
    Long Island
    Posts
    696
    BLindman, Thanks, but I was hoping there was some "magical" alternate way of doing this instead of recompiling objects.

  4. #4
    Join Date
    Jun 2003
    Location
    Ohio
    Posts
    12,592
    Provided Answers: 1
    Try this modified code:
    Code:
    print 'Abracadabra...shazaam!'
    
    ------------------------------------------------------------------------------------------------------------------------
    DESCRIPTION:	Recompiles all the code objects in a database.
    ------------------------------------------------------------------------------------------------------------------------
    REVISION HISTORY:
    EDITOR			DATE		REVISIONS
    blindman		08/2007		Script created.
    blindman		11/19/2008		Modified to handle different schemas.
    ------------------------------------------------------------------------------------------------------------------------
    */
    begin
    
    set nocount on
    create table #SQLStrings (StringID bigint identity(1, 1), SQLString varchar(max))
    create table #CompileErrors (ErrorMessage varchar(4000))
    declare	@SQLString varchar(max)
    declare	@ObjectName varchar(500)
    declare	@ObjectType varchar(10)
    
    declare CodeObjectList cursor for
        select	[schemas].[name] + '.' + [objects].[name], [objects].[type]
        from	sys.objects objects
    			inner join sys.schemas schemas on objects.schema_id = schemas.schema_id
        where	type in ('P', 'TR', 'V', 'TF', 'FN', 'IF')
    			and objects.name <> 'RecompileSQLCode'
        order by parent_object_id
    
    open CodeObjectList
    fetch next from CodeObjectList into @ObjectName, @ObjectType
    while @@fetch_status = 0
        begin
        truncate table #SQLStrings
        insert into #SQLStrings exec sp_helptext @ObjectName
        set @SQLString = ''
        select  @SQLString = @SQLString + ltrim(SQLString) from #SQLStrings order by StringID
    
        set	@SQLString = left(@SQLString, charindex('CREATE ', @SQLString)-1) + 'ALTER ' + right(@SQLString, len(@SQLString)-charindex('CREATE ', @SQLString) -6)
    
        begin try
    	exec (@SQLString)
        end try
        begin catch
    	insert into #CompileErrors (ErrorMessage) values (@ObjectName + ' (' + rtrim(@ObjectType) + '): ' + error_message())
        end catch
        fetch next from CodeObjectList into @ObjectName, @ObjectType
        end
    
    close CodeObjectList
    deallocate CodeObjectList
    
    select * from #CompileErrors
    
    drop table #SQLStrings
    drop table #CompileErrors
    
    end
    If it's not practically useful, then it's practically useless.

    blindman
    www.chess.com: "sqlblindman"
    www.LobsterShot.blogspot.com

  5. #5
    Join Date
    Jun 2012
    Posts
    4

    An alternative approach (doesn't require compiling objects)

    Another possible solution would be to write a TSQL script that identifies & loops through all user-defined stored procs, functions, and views; and in each iteration, perform the following:

    1. Find any/all db object references (via the sp_depends system stored procedure).

    2. Check for the existence of referenced db object(s) (via the object_id system function).

    3. Print the name of the “bad” stored proc/function/view.

  6. #6
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    sp_depends does not totally work anymore.

    I would not recompile every proc in production database, but I see no problem with Blindman's approach in any offline environment like development, QA, UAT or training.
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  7. #7
    Join Date
    Jun 2012
    Posts
    4

    in lieu of using sp_depends...

    you can select from the sys.dm_sql_referenced_entities system view

  8. #8
    Join Date
    Jun 2003
    Location
    Ohio
    Posts
    12,592
    Provided Answers: 1
    My code so pretty. So pretty my code.
    If it's not practically useful, then it's practically useless.

    blindman
    www.chess.com: "sqlblindman"
    www.LobsterShot.blogspot.com

  9. #9
    Join Date
    Nov 2002
    Location
    Jersey
    Posts
    10,322
    We create regression scripts that test all of our sprocs that we maintain and update and run before every release
    Brett
    8-)

    It's a Great Day for America everybody!

    dbforums Yak CorralRadio 'Rita
    dbForums Member List
    I'm Good Once as I ever was

    The physical order of data in a database has no meaning.

  10. #10
    Join Date
    Jun 2003
    Location
    Ohio
    Posts
    12,592
    Provided Answers: 1
    Just curious Brett...
    What are the most common issues your regression scripts detect?
    If it's not practically useful, then it's practically useless.

    blindman
    www.chess.com: "sqlblindman"
    www.LobsterShot.blogspot.com

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •