How to Move TempDB Files to a Different Drive or Folder?
Moving the TempDB files is a 2-step process:
- Tell SQL where you want your new TempDB files to go to
- Restart the
SQL Server
service for the change to take effect
To tell SQL where to create the new TempDB files, you can use:
DECLARE @newDriveAndFolder VARCHAR(8000);
SET @newDriveAndFolder = 'Z:\YourTempDBfolder';
SELECT [name] AS [Logical Name]
,physical_name AS [Current Location]
,state_desc AS [Status]
,size / 128 AS [Size(MB)] --Number of 8KB pages / 128 = MB
,'ALTER DATABASE tempdb MODIFY FILE (NAME = ' + QUOTENAME(f.[name])
+ CHAR(9) /* Tab */
+ ',FILENAME = ''' + @newDriveAndFolder + CHAR(92) /* Backslash */ + f.[name]
+ CASE WHEN f.[type] = 1 /* Log */ THEN '.ldf' ELSE '.mdf' END + ''''
+ ');'
AS [Create new TempDB files]
FROM sys.master_files f
WHERE f.database_id = DB_ID(N'tempdb')
ORDER BY f.[type];
This will generate the T-SQL statements you need to run to move the files to the new drive:\folder
you want. (click image to make larger)
When you have ran your moving statements, you can run the above query again, to check that the Current Location
column is now showing your new drive:\folder
.
Once you're happy with your changes, restart the SQL Server service.
The calculation of the size(MB) in the script above is off. Don't forget that size in sys.master_files is the number of 8KB pages. Here is the correct script:
DECLARE @newDriveAndFolder VARCHAR(8000);
SET @newDriveAndFolder = 'Z:\YourTempDBfolder';
SELECT [name] AS [Logical Name]
,physical_name AS [Current Location]
,state_desc AS [Status]
,size*8/1024 AS [Size(MB)] --Number of 8KB pages dived by 1024
,'ALTER DATABASE tempdb MODIFY FILE (NAME = ' + QUOTENAME(f.[name])
+ CHAR(9) /* Tab */
+ ',FILENAME = ''' + @newDriveAndFolder + CHAR(92) /* Backslash */ + f.[name]
+ CASE WHEN f.[type] = 1 /* Log */ THEN '.ldf' ELSE '.mdf' END + ''''
+ ');'
AS [Create new TempDB files]
FROM sys.master_files f
WHERE f.database_id = DB_ID(N'tempdb')
ORDER BY f.[type];