Add Data or Log Files to a Database
Applies to: SQL Server
This topic describes how to add data or log files to a database in SQL Server by using SQL Server Management Studio or Transact-SQL.
In This Topic
Before you begin:
To add data or log files to a database, using:
Before You Begin
Limitations and Restrictions
You cannot add or remove a file while a BACKUP statement is running.
A maximum of 32,767 files and 32,767 filegroups can be specified for each database.
Security
Permissions
Requires ALTER permission on the database.
Using SQL Server Management Studio
To add data or log files to a database
In Object Explorer, connect to an instance of the SQL Server Database Engine and then expand that instance.
Expand Databases, right-click the database from which to add the files, and then click Properties.
In the Database Properties dialog box, select the Files page.
To add a data or transaction log file, click Add.
In the Database files grid, enter a logical name for the file. The file name must be unique within the database.
Select the file type, data or log.
For a data file, select the filegroup in which the file should be included from the list, or select <new filegroup> to create a new filegroup. Transaction logs cannot be put in filegroups.
Specify the initial size of the file. Make the data file as large as possible, based on the maximum amount of data you expect in the database.
To specify how the file should grow, click (...) in the Autogrowth column. Select from the following options:
To allow for the currently selected file to grow as more data space is required, select the Enable Autogrowth check box and then select from the following options:
To specify that the file should grow by fixed increments, select In Megabytes and specify a value.
To specify that the file should grow by a percentage of the current file size, select In Percent and specify a value.
To specify the maximum file size limit, select from the following options:
To specify the maximum size the file should be able to grow to, select Restricted File Growth (MB) and specify a value.
To allow for the file to grow as much as needed, select Unrestricted File Growth.
To prevent the file from growing, clear the Enable Autogrowth check box. The size of the file will not grow beyond the value specified in the Initial Size (MB) column.
Note
The maximum database size is determined by the amount of disk space available and the licensing limits determined by the version of SQL Server that you are using.
Specify the path for the file location. The specified path must exist before adding the file.
Note
By default, the data and transaction logs are put on the same drive and path to accommodate single-disk systems, but may not be optimal for production environments. For more information, see Database Files and Filegroups.
Click OK.
Using Transact-SQL
To add data or log files to a database
Connect to the Database Engine.
From the Standard bar, click New Query.
Copy and paste the following example into the query window and click Execute. The example adds a filegroup with two files to a database. The example creates the filegroup
Test1FG1
in theAdventureWorks2022
database and adds two 5-MB files to the filegroup.
USE master
GO
ALTER DATABASE AdventureWorks2022
ADD FILEGROUP Test1FG1;
GO
ALTER DATABASE AdventureWorks2022
ADD FILE
(
NAME = test1dat3,
FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\t1dat3.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
),
(
NAME = test1dat4,
FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\t1dat4.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
)
TO FILEGROUP Test1FG1;
GO
For more examples, see ALTER DATABASE File and Filegroup Options (Transact-SQL).
See Also
Database Files and Filegroups
Delete Data or Log Files from a Database
Increase the Size of a Database