March 28, 2014 at 8:15 am
Hello Everyone, and Happy Friday!
I am doing some general housekeeping for a couple of our SQL boxes in the Development environment. All the databases are set to Simple recovery mode. No need in anything else for these boxes. I have a database on all the boxes named "DatabaseMaintenance" Keeps things like all the sprocs for any type of database maintenance, etc....
I would like to schedule a single sproc that is located in the DatabaseMaintenance database to shrink the Transaction logs on a set schedule. They sometimes grow quite large while testing and developing. The thing that I cannot seem to get around, is when using the ShrinkFile command, one must use the Log Name. If this code is in a sproc that is located in the DatabaseMaintenance database, it will fail when attempting to call out to a different database. Because the Log does not exist on the database that the sproc is located.
How can I get around this small dilemma? There are only about 10 databases per box. To a point we really do not care what happens to them. They are on a Full backup schedule daily, just to keep the objects. As I stated previously, the logs will still grow huge at times while pumping data.
Is there a way to create a piece of code that will run against each database on the server, and be stored in a single database? Other than the system databases of course.
Thank you in advance for all your assistance, suggestions and comments.
Andrew SQLDBA
March 31, 2014 at 10:19 am
Hi Andrew,
I have created this for you from a similar maintenance task I undertake:
EXEC sp_MSforeachdb 'IF ''?'' NOT IN (''tempDB'',''model'',''msdb'', ''master'')
BEGIN
DECLARE @desiredSizeInMB INT = 16, @execSQL NVARCHAR(MAX)
SELECT @execSQL =
''DBCC SHRINKFILE ('' + NAME + '' ,'' + CAST(@desiredSizeInMB AS VARCHAR(4)) + '' ) WITH NO_INFOMSGS;''
FROM
[?].[sys].[database_files] AS DF
WHERE
[type] = 1
use [?];
EXEC sp_executesql @execSQL
END'
Edited - actually execute the SQL!
🙂
gsc_dba
March 31, 2014 at 10:30 am
Andrew in my shop, all databases on development boxes are switched over to simple recovery mode; i don't need a point in time restore on development that log backups would provide me; would it be an option to change them to simple recovery and shrink the logs once, isntead of letting them remain in full recovery?
Lowell
March 31, 2014 at 11:30 am
Hey Lowell
Yes, in fact they are already in Simple recovery mode. But with the amount of data being pumped int at times, they can grow. And over time, they get big. Not large, just big, and I was asked to do what I can do to save as much drive space as possible. On this box, 10 - 15GB is a nice amount of drive space.
Thanks for your suggestions, comments and answer to my question
Andrew SQLDBA
March 31, 2014 at 11:33 am
Thanks GSC_DBA
That is really Great!! I tried using MS_ForEachDatabase, but could not get it working correctly. I was missing something in the dynamic code, and could not get it correct.
I will give this a try and see if this works. It looks better than what I have written 🙂
I greatly appreciate your time, code, comment and suggestion.
Andrew SQLDBA
March 31, 2014 at 3:19 pm
Or, as something a tad easier:
exec sp_MSforeachDB 'USE [?]; IF ''?'' NOT in (''master'',''model'',''msdb'',''tempDB'') DBCC ShrinkFile(2,10)'
Untested, so may have syntax errors. Test before use.
Shrinkfile takes either the file name or the file ID as the first parameter, and the first log file is always file ID 2 (and if you have more than one log file, that needs fixing)
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
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply