Skip to content

Commit 20b9299

Browse files
Update Incremental Shrink.txt
Change it from script to stored procedure - Add functionality to go through all data files
1 parent 9ca6bf9 commit 20b9299

File tree

1 file changed

+73
-54
lines changed

1 file changed

+73
-54
lines changed

Incremental Shrink.txt

+73-54
Original file line numberDiff line numberDiff line change
@@ -1,86 +1,105 @@
1+
CREATE OR ALTER PROCEDURE usp_IncrementalShrink
2+
@DesiredFileSize int=0,
3+
@ShrinkChunkSize int=5,
4+
@dbFileID int =0
5+
as
6+
begin
17
/***********************************************
2-
Incremental Shrink for data file - Azure SQL
8+
Incremental Shrink for data file - SQL Server, Azure SQL, Azure Managed Instance
39
************************************************/
410
/*-------------------------------------------------
511
Change Log:
12+
2022-07-12 - Change it from script to stored procedure
13+
- Add functionality to go through all data files
614
2022-07-06 - more accurate current size validation.
715

816
*/-----------------------------------------------
9-
1017
set nocount on
1118
declare @AllocatedSpaceMB int
12-
declare @DesiredFileSize int
13-
declare @ShrinkChunkSize int
1419
declare @UsedSpaceMB int
15-
declare @ErrorIndication int
16-
declare @dbFileID int = 1
20+
declare @UnusedSpaceMB int
21+
declare @ErrorIndication int=0
1722
declare @dbFileType sysname
1823
declare @lastSize int
1924
declare @SqlCMD nvarchar(max)
2025
declare @MSG nvarchar(100)
26+
declare @iFileList table(i int)
27+
declare @iTMP table(i int)
28+
declare @iFileID int
29+
declare @iCurrentSizeTarget int
2130

2231

23-
/*set this values for the current operation, size is in MB*/
24-
set @DesiredFileSize = 30
25-
set @ShrinkChunkSize = 5
26-
32+
set @MSG = convert(nvarchar,getdate())+' - Starting incremental shrink procedure'; raiserror(@msg,0,0) with nowait
2733

28-
SELECT @AllocatedSpaceMB = SIZE/128.0
29-
, @UsedSpaceMB = cast(fileproperty(name, 'SpaceUsed') AS int)/128.0
30-
, @dbFileType = type_desc
31-
--,@UnusedSpaceMB = (SIZE/128.0) - cast(fileproperty(name, 'SpaceUsed') AS int)/128.0
32-
FROM sys.database_files
33-
WHERE file_id = @dbFileID
3434

35-
set @msg = 'Selected File Type and ID: ' + @dbFileType + '(' + cast(@dbFileID as varchar(2)) + ')'
36-
raiserror(@msg,0,0) with nowait
37-
set @msg = 'Current File Size: ' + cast(@AllocatedSpaceMB as varchar(10)) + 'MB'
38-
raiserror(@msg,0,0) with nowait
39-
set @msg = 'Actual used Size: ' + cast(@UsedSpaceMB as varchar(10)) + 'MB'
40-
raiserror(@msg,0,0) with nowait
41-
set @msg = 'Desired File Size: ' + cast(@DesiredFileSize as varchar(10)) + 'MB'
42-
raiserror(@msg,0,0) with nowait
43-
set @msg = 'Interation shrink size: ' + cast(@ShrinkChunkSize as varchar(10)) + 'MB'
44-
raiserror(@msg,0,0) with nowait
35+
/* @dbFileID=0 -> All Files, or actual data file ID */
36+
insert into @iFileList select file_id from sys.database_files where type=0/*Rows*/ and (@dbFileID=0 or file_id=@dbFileID)
4537

4638

47-
set @ErrorIndication =
48-
case
49-
when @DesiredFileSize > @AllocatedSpaceMB then 1
50-
when @UsedSpaceMB > @DesiredFileSize then 2
51-
else 0 end
52-
5339
-- check if there is paused resumable index operation on this DB
5440
-- existance of these types of operations block the shrink operation from reducing the file size
55-
if (SELECT count(*)
56-
FROM sys.index_resumable_operations)>0 set @ErrorIndication=3
41+
if (SELECT count(*) FROM sys.index_resumable_operations)>0 set @ErrorIndication=3
42+
43+
44+
5745

5846

59-
if @ErrorIndication=1 raiserror('[Error] Desired size bigger than current size',16,0) with nowait
60-
if @ErrorIndication=2 raiserror('[Error] Used size is bigger then desired size',16,0) with nowait
6147
if @ErrorIndication=3 raiserror('[Error] Paused resumable index rebuild was detected, please abort or complete the operation before running shrink',16,0) with nowait
62-
if @ErrorIndication=0 raiserror('Desired Size check - OK',0,0) with nowait
6348

6449

65-
set @lastSize = @AllocatedSpaceMB+1
66-
while @AllocatedSpaceMB > @DesiredFileSize /*check if we got the desired size*/ and @lastSize>@AllocatedSpaceMB /* check if there is progress*/ and @ErrorIndication=0
67-
begin
68-
set @msg = cast(getdate() as varchar(100)) + ' - Iteration starting'
69-
raiserror(@msg,0,0) with nowait
7050

71-
select @lastSize = size/128.0
72-
from sys.database_files
73-
where file_id=@dbFileID
51+
/*Go throgh all files pending to be shrinked*/
52+
WHILE (select count(*) from @iFileList)>0
53+
Begin
54+
set @MSG = REPLICATE('-',50); raiserror(@msg,0,0) with nowait
55+
56+
/*Iterate on specific file*/
57+
delete top (1) from @iFileList output deleted.i into @iTMP
58+
select top 1 @iFileID=i from @iTMP
59+
60+
set @MSG = 'Running shrink file on file ID = ' + CONVERT(varchar,@iFileID) +char(13) ; raiserror(@msg,0,0) with nowait
61+
62+
SELECT
63+
@AllocatedSpaceMB = SIZE/128.0
64+
, @UsedSpaceMB = cast(fileproperty(name, 'SpaceUsed') AS int)/128.0
65+
, @UnusedSpaceMB = (SIZE/128.0) - cast(fileproperty(name, 'SpaceUsed') AS int)/128.0
66+
FROM sys.database_files
67+
WHERE file_id = @iFileID
68+
69+
set @MSG = char(9)+'Information about file ID = ' + CONVERT(varchar,@iFileID) ; raiserror(@msg,0,0) with nowait
70+
set @MSG = char(9)+char(9)+'Allocated Space MB = ' + CONVERT(varchar,@AllocatedSpaceMB) ; raiserror(@msg,0,0) with nowait
71+
set @MSG = char(9)+char(9)+'Used Space MB = ' + CONVERT(varchar,@UsedSpaceMB) ; raiserror(@msg,0,0) with nowait
72+
set @MSG = char(9)+char(9)+'Unused Space MB = ' + CONVERT(varchar,@UnusedSpaceMB) ; raiserror(@msg,0,0) with nowait
73+
74+
75+
76+
set @lastSize = @AllocatedSpaceMB+1
77+
while @AllocatedSpaceMB > @DesiredFileSize /*check if we got the desired size*/ and @lastSize>@AllocatedSpaceMB /* check if there is progress*/ and @ErrorIndication=0
78+
begin
79+
set @MSG = char(9)+char(9)+char(9)+convert(nvarchar,getdate()) + ' - Calling ShrinkFile' ; raiserror(@msg,0,0) with nowait
80+
81+
select @lastSize = size/128.0
82+
from sys.database_files
83+
where file_id=@iFileID
84+
85+
/*Calculate next target size and make sure we do not go below 0*/
86+
set @iCurrentSizeTarget = @AllocatedSpaceMB-@ShrinkChunkSize
87+
set @iCurrentSizeTarget = iif(@iCurrentSizeTarget>0, @iCurrentSizeTarget,0)
88+
89+
set @sqlCMD = N'dbcc shrinkfile('+cast(@iFileID as varchar(7))+','+ convert(nvarchar,@iCurrentSizeTarget) +') with no_infomsgs;'
90+
--print @sqlCMD
91+
exec(@sqlCMD)
92+
93+
select @AllocatedSpaceMB = size/128.0
94+
from sys.database_files
95+
where file_id=@iFileID
7496

75-
set @sqlCMD = 'dbcc shrinkfile('+cast(@dbFileID as varchar(7))+','+ cast(@AllocatedSpaceMB-@ShrinkChunkSize as varchar(7)) +') with no_infomsgs;'
76-
exec(@sqlCMD)
97+
set @MSG = char(9)+char(9)+char(9)+convert(nvarchar,getdate()) + ' - ShrinkFile completed. current size is: ' + cast(@AllocatedSpaceMB as varchar(10)) + 'MB'; raiserror(@msg,0,0) with nowait
98+
end
7799

78-
select @AllocatedSpaceMB = size/128.0
79-
from sys.database_files
80-
where file_id=@dbFileID
100+
delete from @iTMP
101+
End
81102

82-
set @msg = cast(getdate() as varchar(100)) + ' - Iteration completed. current size is: ' + cast(@AllocatedSpaceMB as varchar(10)) + 'MB'
83-
raiserror(@msg,0,0) with nowait
84-
end
103+
set @MSG = convert(nvarchar,getdate())+' - Finished incremental shrink procedure'; raiserror(@msg,0,0) with nowait
104+
END
85105

86-
print 'Done'

0 commit comments

Comments
 (0)