Blog Post

Core Infrastructure and Security Blog
6 MIN READ

Split a file group into multiple data files

SQLPFE's avatar
SQLPFE
Brass Contributor
Mar 15, 2019

First published on MSDN on Mar 03, 2017
Periodically we are asked how to split an existing filegroup into multiple data files. The quick answer is that SQL Server does not have a built-in way for you to do that automatically, but you can do it yourself. The process is relatively simple and I have provided a script that demonstrates one technique. The script provided is not designed for production and is only provided for illustrative purposes.

There have been many articles in the past that talk about using the ALTER INDEX …. REBUILD option to move objects from one filegroup to another and to "rebalance" that way. This author acknowledges the benefits of that technique, but sometimes the question of "rebalancing" is more driven out of simple "geometry" constraints. For example, if I have a database on a volume that I cannot grow, and I simply want to add new files to the filegroup – but have those files reside on a different volume. Adding the new files is quite simple, but by default, the existing file remains essentially full and there is an imbalance between the old and new files.

The technique proposed here will effectively rebalance and move the data out of the existing file across to the new files in such a way that the original file can be reduced in size and thus free up space on a volume that is filling up. It should be noted that while this technique "moves" data from the original file to the new files in the same filegroup, it does not guarantee that all objects residing in the filegroup are "balanced". Some objects, depending upon their location in the original datafile, may have some data move, all data move or no data move. Ultimately the total amount of allocated pages will be balanced among the various files in the filegroup, but there could still be some hotspots for certain objects. This article and associated script does not attempt to deal with that issue.

High level process for splitting a filegroup into multiple files  

  • Add several new empty data files to the file group
  • Cap the new files so they cannot auto grow
  • Empty the original data file
  • Readjust all files so they each have the same amount of free space / re-enable autogrowth
  • Shrink the original datafile to the same size of the new files

This process works well and can be done "online" – that is, the objects in the filegroup can be accessed during the splitting process. You should take into consideration that there could be a lot of I/O during this process. In addition to potential performance impacts, databases that participate in an AlwaysOn Availability Group, database mirroring or even log shipping can also be impacted due to the number of log records that are generated – all of which need to be shipped to the respective secondar(ies).

This diagram depicts the intended outcome – to take a filegroup with a single data file in it, and split it into multiple data files.



Step 1: Add new data files to the filegroup 

The first step in splitting a filegroup into multiple data files is to add one or more new empty data files to the filegroup. In this example, the desired goal is for the original file in the filegroup to be 1/4 th its original size and have a total of 4 files of equal size in the filegroup.



In order to do this, we need to add 3 new data files to the filegroup that are each 1/4 th the size of the original data file.

--add (@numfiles-1) files to file group
SELECT @loopcntr = 2;
WHILE @loopcntr <= @numfiles BEGIN
    SELECT @NewLogicalName = @LogicalName + '_' + CAST(@loopcntr as varchar(5))
    SELECT @NewPhysicalName = REPLACE(@PhysicalName , '.mdf', '_' + CAST(@loopcntr as varchar(5))+'.ndf')
    SELECT @sql = 'ALTER DATABASE [' + DB_NAME() + '] ADD FILE ('+ @crlf    +
            'NAME = ' + @NewLogicalName + ',' + @crlf + 
            'FILENAME = ' + QUOTENAME(@NewPhysicalName, '''') + ',' + @crlf + 
            'SIZE = ' + CAST(@NewFSizeMB as VARCHAR(max)) + 'MB,' + @crlf +
            'MAXSIZE = ' + CAST(@NewFSizeMB as VARCHAR(max)) + 'MB,' + @crlf + 
            'FILEGROWTH = 0MB) TO FILEGROUP ' + QUOTENAME(@FileGroupName) +';' + @crlf + @crlf
    PRINT @sql
    exec (@sql)
    SELECT @loopcntr += 1
END

Step 2: Disable autogrowth on the new data files 

The reason for this will become clear in the next step. In the sample script provided with this article, step 2 was actually done in combination with step 1 by setting the FILEGROWTH parameter to "0MB" in the ALTER DATABASE … ADD FILE command. (see above code segment).

Step 3: "Empty" the original data file  

After the new files have been "capped" we are ready to "rebalance". This is done by executing a DBCC SHRINKFILE command on the original data file with the EMPTYFILE option. This will take the data from the "end of the data file" and move it into the 3 newly added data files. Since each of those files have the same free space in them, the proportional fill algorithm will evenly distribute the data from the original file into the three new files.

The filegroup will go from this



To this:

--empty the original file -- which will move data into the new files
SELECT @sql = 'BEGIN TRY' + @crlf +
        'DBCC SHRINKFILE (' + @LogicalName + ', EMPTYFILE)' + @crlf +
        'END TRY' + @crlf + 
        'BEGIN CATCH' + @crlf + 
        '   IF ERROR_NUMBER() <> 2556 BEGIN' + @crlf + 
        '      SELECT ERROR_NUMBER(), ERROR_MESSAGE()' + @crlf + 
        '      RAISERROR (''Severe error moving data into new files.  MANUAL cleanup necessary.  Terminating connection...'', 19, 1) WITH LOG' + @crlf +
        '   END' + @crlf + 
        'END CATCH' + @crlf + @crlf
PRINT @SQL
exec (@sql)

The reason we disabled autogrowth on the three new files is to prevent the original file from getting "too empty". In this example, we want 4 files of equal size when we're done. If we had not prevented the 3 new files from autogrowing, they would have kept growing until the first file was either empty or until all objects capable of moving had been moved. This would not have left us in a balanced state, but in a state that would have looked something more like this.


Step 4: Re-enable autogrowth and set the size to match for all datafiles 
At this point we want to make sure that all the files are set to have the same maximum file size and autogrowth paramters. This is done so that if the files become full and need to autogrow, they will be set to grow at the same amount – thus leaving the same amount of free space in all the files.

--set all files to have a MAXSIZE and enable autogrowth
SELECT @loopcntr = 1;
WHILE @loopcntr <= @numfiles BEGIN
    SELECT @NewLogicalName = CASE @loopcntr WHEN 1 then @LogicalName ELSE @LogicalName + '_' + CAST(@loopcntr as varchar(5)) END
    SELECT @sql = 'ALTER DATABASE [' + DB_NAME() + '] MODIFY FILE ('+ @crlf +
            'NAME = ' + @NewLogicalName + ',' + @crlf + 
            'MAXSIZE = ' + @maxsizeMBText + ',' + @crlf + 
            'FILEGROWTH = ' +  @maxgrowthMBText + ');' + @crlf + @crlf
    PRINT @sql
    exec (@sql)
    SELECT @loopcntr += 1
END

Step 5: "Shrink" the original data file to match the filesize of the other 3 new files 
At this point we can issue another DBCC SHRINKFILE on the first file to shrink the file to be the same size as the other 3 files. The diagram below shows the final state at this point, 4 files of equal size in the filegroup.

--shrink the original file to match the new files size
SELECT @sql = 'BEGIN TRY' + @crlf +
'DBCC SHRINKFILE (' + @LogicalName + ', ' + CAST(@NewFSizeMB as varchar(max))+ ')' + @crlf +
'END TRY' + @crlf +
'BEGIN CATCH' + @crlf +
' IF ERROR_NUMBER() <> 2556 BEGIN' + @crlf +
' SELECT ERROR_NUMBER(), ERROR_MESSAGE()' + @crlf +
' RAISERROR (''Severe error moving data into new files. MANUAL cleanup necessary. Terminating connection...'', 19, 1) WITH LOG' + @crlf +
' END' + @crlf +
'END CATCH' + @crlf
PRINT @SQL
exec (@sql)



Script File

I have included here a .SQL text file containing the example script for this article.

References
For more information regarding how SQL Server deals with multiple files in a file group, please check some of these following references. 

 

Updated Apr 28, 2020
Version 5.0
  • TrayceMS's avatar
    TrayceMS
    Copper Contributor
    I apologize for the reference to my blog that I have ceased to maintain.
    Please find below the script that was referenced in the article.
    If you have any questions - please feel free to reach out to me at email address removed for privacy reasons
     
     
     
    /*=====================================================================
    AUTHOR:    email address removed for privacy reasons
    FILENAME:  SplitFileGroup.sql
    VERSION: 1.1
     
      THIS SCRIPT USES the CTRL-SHIFT-M macro substitution technique to set several variables:
     
    DBName -- The database in which the filegroup exists that should be split.
    FileGroupName -- The name of the filegroup to be split  (default = Primary)
    FileCountAfterSplit -- The total number of files in the filegroup after the split (default = 4)
    MaxFileSize -- The maximum filesize of the files after the split (default=NULL which equals "UNLIMITED")
    AutoGrowthSize -- The size for autogrowth after the split is complete (default NULL = 100MB)
     
     
    OBJECTS CREATED
    ================
    Additional data files added to the specified filegroup.
    The number of data files added will be  ("FileCountAfterSplit" - 1)
    The additional data files are added to same path where the existing data file resides.
     
     
    DESCRIPTION OF ALGORITHM
    =========================
    1) use the same path as the existing file.
    2) get the size of the current file
    3) set the filesize for each of the new files as:  (CurrentFileSize/FileCountAfterSplit) + 1MB
    4) add  (FileCountAfterSplit-1) new files to filegroup
    set the Autogrowth value to 0 (so the files cannot autogrow)
    set the MAXSIZE = to the value supplied in template variable, or UNLIMITED if "NULL" was used
        the "logical" name of each new file is the original file's logical name with an "_x" added to it, where
           x = the number of the added file -- starting with "2"
    the "physical" name of each new file in the original file's phyical name with an "_x" appended to the filename
           where x = the number of the added file -- starting with "2".
    the "extension" for the physical files added will be "ndf"
    5) issue a DBCC SHRINKFILE  with the EMPTYFILE option
        Ignore the error "2556".   This is expected because not everything can be emptied from the origianl data file.
    This is done intentionally so that after the original file is shrunk, all data files will be the same size.
    6) iterate through all data files in the filegroup, setting MAXSIZE and FILEGROWTH to the values
        provided in the template variables.  Defaults being   UNLIMITED  and 100MB respectively
    7) issue a DBCC SHRINKFILE, specifying the new filesize
     
     
     
    NOTES:
    ======
    This script is an example script only.  It is designed to show one technique on how
    to modify a filegroup with a single data to have multiple datafiles and move the
    data from the original file into the new files, so that the result is a filegroup balanced
    fairly evenly among all of the data files.
     
    This script should not be run in production environments.  It is provided for illustrative purposes only
    and is provided "AS IS" with no warranties.
     
    This script is designed to split a filegroup that only contains a single datafile.
    This script DOES NOT split the PRIMARY filegroup (since some objects can't be moved)
       (note--- If you really "need" to split the primary filegroup original datafile
    you can do it with the technique in this script/article.  Just realize
        that because some objects can't be moved, the space allocation afterward my not be
    exactly even or uniform).
     
    This script DOES NOT check for adquate file space.
    This script DOES NOT do any significant error checking.
    This script DOES NOT attempt to handle any "undo" or "rollback" process should an error occur.
    If the MaxFileSize specified is less than the calculated new size, the MaxFileSize will be set
      to the calculated new size + 10MB.
    Depending on the exact amount of used space in the original file, and the number of files
      specified to split into, the amount of used space in the original file may be somewhat
      less or more than the other files.   This script is not designed to ensure that every
      file is of exact equal size and used space amounts.   All files should be close in 
      used space though -- if not, please send me an email - I would like to discuss.
         
     
    REVISION HISTORY:
    =================
    20170208 1.1 Initial Release
    ======================================================================*/
     
    SET NOCOUNT ON
    USE [<DBName, sysname, SplitFileGroupDB>]
    GO
     
    DECLARE @FileGroupName sysname ='<FileGroupName, sysname, Primary>';
    DECLARE @numfiles INT = <FileCountAfterSplit, smallint, 4>;
    DECLARE @maxsizeMB INT = <MaxFileSize (NULL = unlimited), smallint, NULL>;
    DECLARE @maxgrowthMB INT= <AutoGrowthSize (MB) (NULL = 100), smallint, NULL>;
     
    DECLARE @maxsizeMBText VARCHAR(max) = 'UNLIMITED';
    DECLARE @maxgrowthMBText VARCHAR(max) = '100MB';
    DECLARE @crlf CHAR(2) = CHAR(13)+CHAR(10);
    DECLARE @sql VARCHAR(max);
    DECLARE @loopcntr INT;
    DECLARE @FGFileCount INT;
    DECLARE @FSizeMB DECIMAL(19,2), @LogicalName sysname, @PhysicalName sysname, @MaxSize INT;
    DECLARE @NewFSizeMB INT, @NewLogicalName sysname, @NewPhysicalName sysname;
     
    IF @maxgrowthMB IS NOT NULL
    SELECT @maxgrowthMBText = CAST(@maxgrowthMB as varchar(max)) + 'MB'
     
    SELECT @FGFileCount = COUNT(*) FROM sys.database_files df
    INNER JOIN sys.filegroups fg on df.data_space_id = fg.data_space_id
    WHERE fg.name = @FileGroupName
     
    IF ((@FileGroupName = 'Primary')) BEGIN
    RAISERROR('SplitFileGroup.sql message:  This script does not split the primary filegroup.    Aborting.', 10,1)
    RETURN
    END
    IF ((@FGFileCount IS NULL) or @FGFileCount = 0) BEGIN
    RAISERROR('SplitFileGroup.sql message:  Filegroup [%s] does not exist.    Aborting.', 10,1, @FileGroupName)
    RETURN
    END ELSE IF (@FGFileCount > 1) BEGIN
    RAISERROR('SplitFileGroup.sql message:  The procedure is designed for splitting a filegroup with only 1 file in it.  Filegroup [%s] contains <%d> files.    Aborting.', 10,1, @FileGroupName, @FGFileCount)
    RETURN
    END
     
    --if we get here, we have only 1 file in the filegroup --we will proceed
     
    --get the used amount of space and other info from current file in filegroup
    SELECT @FSizeMB = (SUM(au.[total_pages])/(1024.*1024))*8192, 
    @NewFSizeMB = CAST(1+((SUM(au.[total_pages])/(1024.*1024))*8192)/@numfiles as INT)
    FROM sys.allocation_units au 
    INNER JOIN sys.filegroups fg on fg.data_space_id = au.data_space_id
    WHERE fg.name = @FileGroupName
     
    IF @maxsizeMB IS NOT NULL BEGIN
    IF @maxSizeMB < @NewFSizeMB  BEGIN
    SELECT @maxSizeMB = @NewFSizeMB + 10
    END
    SELECT @maxsizeMBText = CAST(@maxsizeMB as varchar(max)) + 'MB'
    END
     
    SELECT 
    @LogicalName = df.[name], 
    @PhysicalName = df.[physical_name]
    FROM sys.database_files df
    INNER JOIN sys.filegroups fg on df.data_space_id = fg.data_space_id
    WHERE fg.name = @FileGroupName
     
    --add (@numfiles-1) files to file group
    SELECT @loopcntr = 2;
    WHILE @loopcntr <= @numfiles BEGIN
    SELECT @NewLogicalName = @LogicalName + '_' + CAST(@loopcntr as varchar(5))
    SELECT @NewPhysicalName = REPLACE(@PhysicalName , RIGHT(@PhysicalName,4), '_' + CAST(@loopcntr as varchar(5))+'.ndf')
    SELECT @sql = 'ALTER DATABASE [' + DB_NAME() + '] ADD FILE ('+ @crlf +
    'NAME = ' + @NewLogicalName + ',' + @crlf + 
    'FILENAME = ' + QUOTENAME(@NewPhysicalName, '''') + ',' + @crlf + 
    'SIZE = ' + CAST(@NewFSizeMB as VARCHAR(max)) + 'MB,' + @crlf +
    'MAXSIZE = ' + CAST(@NewFSizeMB as VARCHAR(max)) + 'MB,' + @crlf + 
    'FILEGROWTH = 0MB) TO FILEGROUP ' + QUOTENAME(@FileGroupName) +';' + @crlf + @crlf
    PRINT @sql
    exec (@sql)
    SELECT @loopcntr += 1
    END
     
    --empty the original file -- which will move data into the new files
    SELECT @sql = 'BEGIN TRY' + @crlf +
    'DBCC SHRINKFILE (' + @LogicalName + ', EMPTYFILE)' + @crlf +
    'END TRY' + @crlf + 
    'BEGIN CATCH' + @crlf + 
    '   IF ERROR_NUMBER() <> 2556 BEGIN' + @crlf + 
            '      SELECT ERROR_NUMBER(), ERROR_MESSAGE()' + @crlf + 
            '      RAISERROR (''Severe error moving data into new files.  MANUAL cleanup necessary.  Terminating connection...'', 19, 1) WITH LOG' + @crlf +
    ' END' + @crlf + 
    'END CATCH' + @crlf + @crlf
    PRINT @SQL
    exec (@sql)
     
    --set all files to have a MAXSIZE and enable autogrowth
    SELECT @loopcntr = 1;
    WHILE @loopcntr <= @numfiles BEGIN
    SELECT @NewLogicalName = CASE @loopcntr WHEN 1 then @LogicalName ELSE @LogicalName + '_' + CAST(@loopcntr as varchar(5)) END
    SELECT @sql = 'ALTER DATABASE [' + DB_NAME() + '] MODIFY FILE ('+ @crlf +
    'NAME = ' + @NewLogicalName + ',' + @crlf + 
    'MAXSIZE = ' + @maxsizeMBText + ',' + @crlf + 
    'FILEGROWTH = ' +  @maxgrowthMBText + ');' + @crlf + @crlf
    PRINT @sql
    exec (@sql)
    SELECT @loopcntr += 1
    END
     
    --shrink the original file to match the new files size
    SELECT @sql = 'BEGIN TRY' + @crlf +
    'DBCC SHRINKFILE (' + @LogicalName + ', ' + CAST(@NewFSizeMB as varchar(max))+ ')' + @crlf +
    'END TRY' + @crlf + 
    'BEGIN CATCH' + @crlf + 
    '   IF ERROR_NUMBER() <> 2556 BEGIN' + @crlf + 
            '      SELECT ERROR_NUMBER(), ERROR_MESSAGE()' + @crlf + 
            '      RAISERROR (''Severe error moving data into new files.  MANUAL cleanup necessary.  Terminating connection...'', 19, 1) WITH LOG' + @crlf +
    ' END' + @crlf + 
    'END CATCH' + @crlf
    PRINT @SQL
    exec (@sql)
     
  • rah1077's avatar
    rah1077
    Copper Contributor

    Hi, it's a great article, however, I am unable to get the script file through your link. Thanks!