Review TempDB file size and location and move to New Drive or Folder

Here are some quick scripts to find details about TempDB.  One thing I dislike about other scripts is that they calculate the MB size by [SIZE]*8/1024 which can be reduced to simply 128.  The other important thing to remember about TempDB is that it is different than a User Created databases as it is recreated on every start up or restart of the SQL Server Service and must look to the master database for its start-up configuration. Any tempdb file growth via ALTER DATABASE works like a user DB but tempdb differs in that it allows the ALTER DATABASE command to re-size a data file to a smaller value upon start/restart, without actually changing the current file size or shrinking out the space. Thus setting a new smaller value is held in master as the initial start-up size and leveraging this makes resizing TempDB as well as adding files to tempdb easier.  

If you ever have to refer to Shrinking tempdb without restarting SQL Server or When Shrinking Tempdb Just Won’t Shrink then you know that just getting things back to a working state is the most important and not everyone can take an outage so having this sitting idle waiting for a restart is great!  If you get into trouble then refer to: How to Start SQL Server Service Without tempdb?


Example: 
-- Get TempDB(Database_ID = 2) File Path info for configured size and current size
USE [master];
GO

--Configured
SELECT DB_NAME( DATABASE_ID ) db_namefile_id, type_desc, name, physical_name, size / 128.0 AS CurrentSizeMB
      ,growth / 128.0 AS CurrentGrowthMB
  FROM sys.master_files
 WHERE database_id = DB_ID'tempdb' )
 ORDER BY type_desc DESCfile_id;
GO

--Current size
SELECT 'tempdb' AS db_namefile_id, type_desc, name, size / 128.0 [TempdbSizeInMB], growth / 128.0 [TempdbGrowthInMB]
  FROM tempdb.sys.database_files
 ORDER BY type_desc DESCfile_id;
GO

-------------------------------------------------------------
-- Generate Alter Statement for New File Location = Update @NewPath = 'HERE'
DECLARE @NewPath VARCHAR(254);
SET @NewPath = 'T:\MSSQL\DATA\';

SELECT 'ALTER DATABASE tempdb MODIFY FILE (NAME = [' + f.name + '],' + ' FILENAME = ''' + @NewPath + '' + f.name
       + CASE
              WHEN f.type = 1 THEN '.ldf'
              ELSE '.mdf' END + ''');'
  FROM sys.master_files f
 WHERE f.database_id = DB_IDN'tempdb' );
-------------------------------------------------------------
-- Generate Syntax for TempDB Datafiles 'ROWS' upon restart of SQL Service
-- Update @ReStart_Size = 'SIZE = XXXMB , FILEGROWTH = XXXMB'; 
DECLARE @ReStart_Size VARCHAR(254);
SET @ReStart_Size = 'SIZE = 200MB , FILEGROWTH = 100MB';

SELECT 'ALTER DATABASE tempdb MODIFY FILE (NAME = [' + f.name + '],' + ' ' + @ReStart_Size + ');'
  FROM sys.master_files f
 WHERE f.database_id = DB_IDN'tempdb' )
 AND f.type_desc='ROWS';
 

Comments

Popular posts from this blog

How to mass update all or some sql server agent job step commands

SQL Monitoring for Blocking and Locking Capture and Log to table with sp_WhoIsActive or sp_BlitzWho

SQL Server General Index Naming Convention