question

Chitra avatar image
Chitra asked

Move tempdb

Can I move the tempdb database to a separate drive and leave the rest of the system databases (master, msdb) on a separate drive? Please advice, I would like to apply this to the production database so that the system does not shutdown.
sql-server-2005tempdbsystem-databases
1 comment
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Tim avatar image Tim commented ·
@user-489 if my answer got you what you needed, do you mind checking the check box to mark it as the answer.
0 Likes 0 ·
Tim avatar image
Tim answered
Yes, use the alter database command. Of course change the drive letter and location in the script below to your naming standard and drive(s). USE master GO ALTER DATABASE TempDB MODIFY FILE (NAME = tempdev, FILENAME = 'e:\tempdb\datatempdb.mdf') GO ALTER DATABASE TempDB MODIFY FILE (NAME = templog, FILENAME = 'f:\tempdb\datatemplog.ldf') GO Then restart your sql service.
6 comments
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Oleg avatar image Oleg commented ·
@TRAD +1 I would like to add just one cent: it is a very good idea to have tempdb on the separate drive, and if there is a need to have more than one tempdb file then it is best to store each on the separate physical drive, so each file gets it own spindle. This implies that tempdb file(s) should never be on the same spindle with any non-system database files if possible.
2 Likes 2 ·
Chitra avatar image Chitra commented ·
Thank you so much for the quick response. I will be running the dry run in dev.
1 Like 1 ·
Mark avatar image Mark commented ·
Yes @Oleg (+1), and you might consider using a SSD for the tempdb.
1 Like 1 ·
Blackhawk-17 avatar image Blackhawk-17 commented ·
Short and sweet.
0 Likes 0 ·
Tim avatar image Tim commented ·
That is what we are here for. So many others have helped me out on here, it is nice to give back.
0 Likes 0 ·
Show more comments
Kev Riley avatar image
Kev Riley answered
Just to add...tempdb is recreated each time the SQL Service starts, hence why you have to restart after changing the locations, so be aware that the 'old' tempdb files will still exist in the original location once you have restarted. These can be safely deleted once the 'new' tempdb is being used.
1 comment
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

KenJ avatar image KenJ commented ·
Good follow-up. Seeing the leftover files can be a bit misleading.
0 Likes 0 ·
ozamora avatar image
ozamora answered
Also, just to add, size the tempdb data files properly so they do not autogrow in tiny chunks every time causing unnecessary fragmentation. Same goes for the log file. Take into consideration that the log file can take some time to create at service startup if its large, as the database will zero-out the file.
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

ozamora avatar image
ozamora answered
Just one more note, 1 tempdb file per processor core is a [myth][1]. You can start with 1/4 and then go up with 1/2; needs to be tested. [1]: http://www.sqlskills.com/BLOGS/PAUL/post/A-SQL-Server-DBA-myth-a-day-(1230)-tempdb-should-always-have-one-data-file-per-processor-core.aspx
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Scotty avatar image
Scotty answered
I recently read that if your cores are less than 8 go with one per core, then if you have more than 8 start with 8 and increase in units of 4.
1 comment
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Blackhawk-17 avatar image Blackhawk-17 commented ·
It depends... if you tie your cores up with I/O then they can't do other processing at the same time. Each workload will require analysis and a balance.
0 Likes 0 ·

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.