Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
Author |
Topic |
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2007-03-09 : 19:45:01
|
This script can be used to shrink a database file in small increments until it reaches a target free space size.It will loop to execute the DBCC SHRINKFILE command to shrink the database file by the desired increment until it reaches the target free space.It is often better to shrink database files in small increments so that it can make continuous, incremental progress, instead of trying to shrink by a large amount in one command. This makes it easier to shrink a database that must be shrunk by a large amount, and makes it easier to interrupt without losing all progress.-- Shrink_DB_File.sql/*This script is used to shrink a database file inincrements until it reaches a target free space limit.Run this script in the database with the file to be shrunk.1. Set @DBFileName to the name of database file to shrink.2. Set @TargetFreeMB to the desired file free space in MB after shrink.3. Set @ShrinkIncrementMB to the increment to shrink file by in MB4. Run the script*/declare @DBFileName sysnamedeclare @TargetFreeMB intdeclare @ShrinkIncrementMB int-- Set Name of Database file to shrinkset @DBFileName = 'MyDatabaseFileName'-- Set Desired file free space in MB after shrinkset @TargetFreeMB = 1000-- Set Increment to shrink file by in MBset @ShrinkIncrementMB = 50-- Show Size, Space Used, Unused Space, and Name of all database filesselect [FileSizeMB] = convert(numeric(10,2),round(a.size/128.,2)), [UsedSpaceMB] = convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) , [UnusedSpaceMB] = convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) , [DBFileName] = a.namefrom sysfiles adeclare @sql varchar(8000)declare @SizeMB intdeclare @UsedMB int-- Get current file size in MBselect @SizeMB = size/128. from sysfiles where name = @DBFileName-- Get current space used in MBselect @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128.select [StartFileSize] = @SizeMB, [StartUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Loop until file at desired sizewhile @SizeMB > @UsedMB+@TargetFreeMB+@ShrinkIncrementMB begin set @sql = 'dbcc shrinkfile ( '+@DBFileName+', '+ convert(varchar(20),@SizeMB-@ShrinkIncrementMB)+' ) ' print 'Start ' + @sql print 'at '+convert(varchar(30),getdate(),121) exec ( @sql ) print 'Done ' + @sql print 'at '+convert(varchar(30),getdate(),121) -- Get current file size in MB select @SizeMB = size/128. from sysfiles where name = @DBFileName -- Get current space used in MB select @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128. select [FileSize] = @SizeMB, [UsedSpace] = @UsedMB, [DBFileName] = @DBFileName endselect [EndFileSize] = @SizeMB, [EndUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Show Size, Space Used, Unused Space, and Name of all database filesselect [FileSizeMB] = convert(numeric(10,2),round(a.size/128.,2)), [UsedSpaceMB] = convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) , [UnusedSpaceMB] = convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) , [DBFileName] = a.namefrom sysfiles a CODO ERGO SUM |
|
coolerbob
Aged Yak Warrior
841 Posts |
Posted - 2008-11-21 : 09:48:50
|
Doesn't this make restores take longer because each shrink is re-run on restore? |
|
|
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2008-11-21 : 10:03:36
|
quote: Originally posted by coolerbob Doesn't this make restores take longer because each shrink is re-run on restore?
Only if you are applying transaction logs.This isn't meant to be an everyday or routine thing to run. This is meant for situations where your database is much larger than necessary, and you want to remove a lot of space. Like if you have purged a lot of data and you want to shrink a database file from 100 GB to 30 GB.Of course, when you get done you would want to de-fragment or re-index all the tables, because the shrink will cause a lot fragmentation.CODO ERGO SUM |
|
|
petemac
Starting Member
1 Post |
Posted - 2011-10-14 : 07:55:57
|
MichaelI've ran your code but nothing seems to happen. This is the exact code I have run, suspect there is something I haven't changed. I'm not much of a programmer (understatement). I'd be grateful for your help.RegardsPeteMac-- Shrink_DB_File.sql/*This script is used to shrink a database file inincrements until it reaches a target free space limit.Run this script in the database with the file to be shrunk.1. Set @DBFileName to the name of database file to shrink.2. Set @TargetFreeMB to the desired file free space in MB after shrink.3. Set @ShrinkIncrementMB to the increment to shrink file by in MB4. Run the script*/declare @DBFileName sysnamedeclare @TargetFreeMB intdeclare @ShrinkIncrementMB int -- Set Name of Database file to shrinkset @DBFileName = 'Test'-- Set Desired file free space in MB after shrinkset @TargetFreeMB = 1000-- Set Increment to shrink file by in MBset @ShrinkIncrementMB = 50-- Show Size, Space Used, Unused Space, and Name of all database filesselect [FileSizeMB] = convert(numeric(10,2),round(a.size/128.,2)), [UsedSpaceMB] = convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) , [UnusedSpaceMB] = convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) , [DBFileName] = a.namefrom sysfiles adeclare @sql varchar(8000)declare @SizeMB intdeclare @UsedMB int-- Get current file size in MBselect @SizeMB = size/128. from sysfiles where name = @DBFileName-- Get current space used in MBselect @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128.select [StartFileSize] = @SizeMB, [StartUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Loop until file at desired sizewhile @SizeMB > @UsedMB+@TargetFreeMB+@ShrinkIncrementMB begin set @sql = 'dbcc shrinkfile ( '+@DBFileName+', '+ convert(varchar(20),@SizeMB-@ShrinkIncrementMB)+' ) ' print 'Start ' + @sql print 'at '+convert(varchar(30),getdate(),121) exec ( @sql ) print 'Done ' + @sql print 'at '+convert(varchar(30),getdate(),121) -- Get current file size in MB select @SizeMB = size/128. from sysfiles where name = @DBFileName -- Get current space used in MB select @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128. select [FileSize] = @SizeMB, [UsedSpace] = @UsedMB, [DBFileName] = @DBFileName endselect [EndFileSize] = @SizeMB, [EndUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Show Size, Space Used, Unused Space, and Name of all database filesselect [FileSizeMB] = convert(numeric(10,2),round(a.size/128.,2)), [UsedSpaceMB] = convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) , [UnusedSpaceMB] = convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) , [DBFileName] = a.namefrom sysfiles a |
|
|
MrTexasFreedom
Starting Member
13 Posts |
Posted - 2011-12-13 : 20:22:36
|
Can someone comment on the parameters I'd need to use on a micro-shrink of a database as described by these stats (numbers in MB)?This DB is taking up a lot of space and our datacenter is whomping us with disk space fees. I can't take the DB offline at all, but in the evenings, I don't have to worry about impacting the performance and I can rebuild indexes then.All thoughts and suggestions appreciated!mtfquote: Originally posted by Michael Valentine Jones This script can be used to shrink a database file in small increments until it reaches a target free space size.It will loop to execute the DBCC SHRINKFILE command to shrink the database file by the desired increment until it reaches the target free space.CODO ERGO SUM
|
|
|
Kristen
Test
22859 Posts |
Posted - 2011-12-14 : 08:38:39
|
I doubt you have a problem that Micro Shrink will solve. Please post this as a new topic in the relevant forum (e.g. http://www.sqlteam.com/forums/forum.asp?FORUM_ID=41 for "SQL 2008 Administration") and folk will no doubt have suggestions |
|
|
pavelcc
Starting Member
2 Posts |
Posted - 2018-02-22 : 13:20:01
|
This can solve your problem. Create a SP based on the above statement in master db. Then, mark the sp a system sp EXEC sp_ms_marksystemobject 'shrink_incremently'then you can call the sp from any db using use databasenamegoexec 'shrink_incremently'Enjoy...---------------------------------------------------use mastergocreate proc shrink_incrementlyas-- EXEC sp_ms_marksystemobject 'shrink_incremently' -- Shrink_DB_File.sql/*This script is used to shrink a database file inincrements until it reaches a target free space limit.Run this script in the database with the file to be shrunk.1. Set @DBFileName to the name of database file to shrink.2. Set @TargetFreeMB to the desired file free space in MB after shrink.3. Set @ShrinkIncrementMB to the increment to shrink file by in MB4. Run the script*/declare @DBFileName sysnamedeclare @TargetFreeMB intdeclare @ShrinkIncrementMB intdeclare @dbname varchar(100) select @dbname = db_name()-----------------------------------------------select @DBFileName = name from master.sys.master_files where database_id = (select dbid from master.dbo.sysdatabases where name = @dbname and file_id = 1)------------------------------------------------------- Set Name of Database file to shrink--set @DBFileName = 'EDRI'-- Set Desired file free space in MB after shrinkset @TargetFreeMB = 1000-- Set Increment to shrink file by in MBset @ShrinkIncrementMB = 50-- Show Size, Space Used, Unused Space, and Name of all database filesselect[FileSizeMB] =convert(numeric(10,2),round(a.size/128.,2)),[UsedSpaceMB] =convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) ,[UnusedSpaceMB] =convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) ,[DBFileName] = a.namefromsysfiles adeclare @sql varchar(8000)declare @SizeMB intdeclare @UsedMB int-- Get current file size in MBselect @SizeMB = size/128 from sysfiles where name = @DBFileName--select * from sysfiles where name = 'EDRI__DEV'-- Get current space used in MBselect @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128.select [StartFileSize] = @SizeMB, [StartUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Loop until file at desired sizewhile @SizeMB > @UsedMB+@TargetFreeMB+@ShrinkIncrementMBbeginset @sql ='dbcc shrinkfile ( '+@DBFileName+', '+convert(varchar(20),@SizeMB-@ShrinkIncrementMB)+' ) 'print 'Start ' + @sqlprint 'at '+convert(varchar(30),getdate(),121)exec ( @sql )print 'Done ' + @sqlprint 'at '+convert(varchar(30),getdate(),121)-- Get current file size in MBselect @SizeMB = size/128. from sysfiles where name = @DBFileName-- Get current space used in MBselect @UsedMB = fileproperty( @DBFileName,'SpaceUsed')/128.select [FileSize] = @SizeMB, [UsedSpace] = @UsedMB, [DBFileName] = @DBFileNameendselect [EndFileSize] = @SizeMB, [EndUsedSpace] = @UsedMB, [DBFileName] = @DBFileName-- Show Size, Space Used, Unused Space, and Name of all database filesselect[FileSizeMB] =convert(numeric(10,2),round(a.size/128.,2)),[UsedSpaceMB] =convert(numeric(10,2),round(fileproperty( a.name,'SpaceUsed')/128.,2)) ,[UnusedSpaceMB] =convert(numeric(10,2),round((a.size-fileproperty( a.name,'SpaceUsed'))/128.,2)) ,[DBFileName] = a.namefromsysfiles a-----------------------------Life is Good---------------------------- |
|
|
|
|
|
|
|