SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Dynamic SQL to change Recovery Model


Dynamic SQL to change Recovery Model

Author
Message
n00bDBA
n00bDBA
SSC Veteran
SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)

Group: General Forum Members
Points: 266 Visits: 467
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?
higgim
higgim
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1112 Visits: 2623
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
GilaMonster
GilaMonster
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88144 Visits: 45277
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


ScottPletcher
ScottPletcher
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7969 Visits: 7160
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)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
Vegard Hagen
Vegard Hagen
SSChasing Mays
SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)SSChasing Mays (617 reputation)

Group: General Forum Members
Points: 617 Visits: 387
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.



Vegard Hagen
Norwegian DBA, blogger and generally a nice guy who believes the world is big enough for all of us.

@vegard_hagen on Twitter
Blog: Vegard's corner (No actual SQL stuff here - haven't found my niche yet. Maybe some day...)

"It is better to light a candle than to curse the darkness."
(Chinese proverb)


n00bDBA
n00bDBA
SSC Veteran
SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)

Group: General Forum Members
Points: 266 Visits: 467
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 Smile )

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!
GilaMonster
GilaMonster
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88144 Visits: 45277
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 Smile )


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


n00bDBA
n00bDBA
SSC Veteran
SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)SSC Veteran (266 reputation)

Group: General Forum Members
Points: 266 Visits: 467
thanks Gail!

good to know..
ScottPletcher
ScottPletcher
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7969 Visits: 7160
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)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search