• Michael Rybicki (10/17/2012)


    I love that command but for the life of me I can not figure out why it fails if you try to use it to set your RECOVERY model for all you user databases. Here's the script - any insight would solve one of my most puzzling mysteries...

    EXEC sp_MSForEachDB 'if ''?'' NOT IN(''master'', ''model'', ''msdb'', ''tempdb'')

    BEGIN

    use [?]

    print ''?'' + '': SET RECOVERY SIMPLE WITH NO_WAIT''

    ALTER DATABASE [?] SET RECOVERY SIMPLE WITH NO_WAIT

    END

    print ''?'' + '': SET RECOVERY SIMPLE WITH NO_WAIT - DONE'';

    '

    GO

    RESULTS:

    master: SET RECOVERY SIMPLE WITH NO_WAIT - DONE

    Msg 5058, Level 16, State 1, Line 5

    Option 'RECOVERY' cannot be set in database 'tempdb'.

    model: SET RECOVERY SIMPLE WITH NO_WAIT - DONE

    msdb: SET RECOVERY SIMPLE WITH NO_WAIT - DONE

    You can call the "ALTER DATABASE" using sp_executesql to avoid the error.

    EXEC sp_MSForEachDB 'if ''?'' NOT IN(''master'', ''model'', ''msdb'', ''tempdb'')

    BEGIN

    use [?]

    print ''?'' + '': SET RECOVERY SIMPLE WITH NO_WAIT''

    EXEC sp_executesql N''ALTER DATABASE [?] SET RECOVERY SIMPLE WITH NO_WAIT'';

    END

    print ''?'' + '': SET RECOVERY SIMPLE WITH NO_WAIT - DONE'';

    '

    GO

    The SQL Guy @ blogspot[/url]

    @SeanPearceSQL

    About Me[/url]