How to consolidate physical files and rename the logical file name in SQL Server 2000 and in SQL Server 2005 (814576)
The information in this article applies to:
- Microsoft SQL Server 2000 (all editions)
- Microsoft SQL Server 2005 Developer Edition
- Microsoft SQL Server 2005 Enterprise Edition
- Microsoft SQL Server 2005 Express Edition
- Microsoft SQL Server 2005 Standard Edition
- Microsoft SQL Server 2005 Workgroup
SUMMARYIn Microsoft SQL Server 2000 and in MicrosoftSQL Server 2005, you can add, delete, and rename the data
files and the transaction log files. This article explains how to consolidate
physical files, and how to rename the logical file name in SQL Server
2000 and in SQL Server 2005.MORE INFORMATIONConsolidate Physical Files You may have to consolidate files or reduce the number of
physical files for a server that is running SQL Server 2000 or SQL Server 2005. To reduce the
number of physical files, you can delete the files. To consolidate the files,
you can purge inactive transactions. Deleting FilesDeleting a data or a transaction log file removes the file from
the database. However, you cannot remove a file from a database if the file
contains data or transaction log information. You can only remove a file if the
file is empty. If you have data that you want to keep, you can migrate the data
from a data file to other files in the same filegroup. To migrate the data, you
can use a DBCC SHRINKFILE statement and specify the EMPTYFILE clause. Then, SQL
Server no longer allows data to be inserted in the file, and you can delete the
file by using an ALTER DATABASE statement. You cannot migrate the
transaction log data from one log file to another to delete a transaction log
file. Purging Inactive TransactionsTo purge inactive transactions from a transaction log file, you
must truncate or back up the transaction log. When a transaction log file no
longer contains any active or inactive transactions, you can remove the log
file from the database. To remove the log file from the database, use these
steps:
- To shrink data or information in a file and to make the
file empty, run the following Transact-SQL statement:
DBCC SHRINKFILE ('<logical file name>', EMPTYFILE ) - To delete a file from a database, run the following
Transact-SQL statement:
ALTER DATABASE <Database name> REMOVE FILE <logical file name>
IMPORTANT After you add or delete files, create a database backup
immediately. You must create a full database backup before you create a
transaction log backup. Rename Logical File NameTo modify the logical name of a data file or a log file, specify
the logical file name you want to rename by using the Name parameter, and then specify the new logical name for the file by
using the NewName parameter. To rename the logical file, run the following
Transact-SQL statement: ALTER DATABASE <Database name> MODIFY FILE ( NAME = <current_logical_name>, NEWNAME = <new_logical_name>)
Modification Type: | Major | Last Reviewed: | 11/30/2005 |
---|
Keywords: | kbSysAdmin kbinfo kbhowto kbFAQ KB814576 kbAudDeveloper |
---|
|