Dynamic SQL to change Recovery Model

  • Hi all,

    Looking at changing the recovery model of several DBs on a instance. Thought it would be a good one for trying some dynamic sql. If i do a Print it seems to come out correctly. But when i try it I get an error.

    DECLARE @sql NVARCHAR(MAX);

    SET @sql = N'';

    SELECT @sql = @sql + 'ALTER DATABASE ' + name + ' SET RECOVERY SIMPLE WITH NO_WAIT

    GO

    '

    FROM master.sys.databases

    WHERE recovery_model_desc != 'simple'

    -- PRINT @sql;

    EXEC(@sql);

    I get an error message

    Msg 102, Level 15, State 1, Line 2

    Incorrect syntax near 'GO'.

    Any idea what im doing wrong?

  • Probably not the most efficient or elegant way to do it but works for me

    DECLARE @sql NVARCHAR(MAX);

    DECLARE @dbs TABLE

    (

    dbname NVARCHAR(MAX) ,

    done BIT

    )

    DECLARE @dbname NVARCHAR(MAX)

    INSERT INTO @dbs

    ( dbname ,

    done

    )

    SELECT name ,

    0

    FROM master.sys.databases

    WHERE recovery_model_desc <> 'simple'

    WHILE ( SELECT COUNT(*)

    FROM @dbs

    WHERE done = 0

    ) > 0

    BEGIN

    SET @dbname = ( SELECT TOP 1

    dbname

    FROM @dbs

    WHERE done = 0

    )

    SET @sql = 'Alter Database ' + @dbname

    + ' SET RECOVERY SIMPLE WITH NO_WAIT'

    UPDATE @dbs

    SET done = 1

    WHERE dbname = @dbname

    EXEC(@sql)

    PRINT @sql

    END

  • Remove the GO. It is not a T-SQL command, it's a batch-breaker for the client app (SSMS).

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • I'd also suggest changing the:

    WHERE recovery_model_desc != 'simple'

    to:

    WHERE recovery_model_desc != N'simple' AND state_desc = N'ONLINE'

    You're just wasting time trying to change the db's recovery model if it isn't ONLINE.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Also, you do need to be sure if changing recovery model of all databases to simple is really an OK thing to do.

    This change has a significant impact on recoverability.


    Kind regards,

    Vegard Hagen
    Norwegian DBA, occasional blogger and generally a nice guy who believes the world is big enough for all of us.
    @vegard_hagen on Twitter
    Blog: Vegards corner (No actual SQL stuff here - havent found my niche yet. Maybe some day...)

    It is better to light a candle than to curse the darkness. (Chinese proverb)
  • Hi all,

    Thanks for all the replies,

    michael.higgins

    Thanks for another method! reall helpful to see alternate ways..

    GilaMonster

    Interesting, so when using dynamic sql you never put in GO? How is it ran then if you cant use GO to separate statements? I thought some things needed GO like reconfigure (going out of scope i know just interested to learn 🙂 )

    ScottPletcher

    Excellent idea.. makes it a lot cleaner! thank you

    Vegard Hagen

    Yes i agree, im just testing on my own machine at the moment, im trying to get a better grip of dynamic sql and when i saw some of my dbs are in full i thought it was a good chance to to get some practice in!

    Trying to take it to the next level. I wanted to restore a database to a dev box and remove all user accounts as it will only need 1 dev account.

    Again im getting an error.

    DECLARE @sql nvarchar(max)

    SET @sql = ''

    SELECT @sql = @sql+

    'DROP USER '''+name+'''

    '

    FROM sys.database_principals

    WHERE principal_id > 5 AND TYPE != 'R'

    --PRINT @sql

    EXECUTE (@sql)

    Error:

    Msg 102, Level 15, State 1, Line 1

    Incorrect syntax near 'UserA'.

    Thanks all for the help!

  • n00bDBA (10/23/2012)


    Interesting, so when using dynamic sql you never put in GO? How is it ran then if you cant use GO to separate statements?

    Each piece you EXEC is a separate batch

    I thought some things needed GO like reconfigure (going out of scope i know just interested to learn 🙂 )

    Nothing needs GO (well, in SSMS anyway). Some things have to be run in their own batch (create proc), but that doesn't mean you need GO, just that it has to be a single batch.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • thanks Gail!

    good to know..

  • Try using [ ] instead of ' ' around the user name:

    DECLARE @sql nvarchar(max)

    SET @sql = ''

    SELECT @sql = @sql+

    'DROP USER ['+name+'] --<<--

    '

    FROM sys.database_principals

    WHERE principal_id > 5 AND TYPE != 'R'

    --PRINT @sql

    EXECUTE (@sql)

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

Viewing 9 posts - 1 through 8 (of 8 total)

You must be logged in to reply to this topic. Login to reply