Rebuild system databases
Applies to: SQL Server
System databases must be rebuilt to fix corruption problems in the master, model, msdb, or resource system databases, or to modify the default server-level collation. This article provides step-by-step instructions to rebuild system databases in SQL Server.
This article is unrelated to rebuilding indexes.
Limitations
When the master
, model
, msdb
, and tempdb
system databases are rebuilt, the databases are dropped and recreated in their original location. If a new collation is specified in the rebuild statement, the system databases are created using that collation setting. Any user modifications to these databases are lost. For example, you might have user-defined objects in the master
database, scheduled jobs in msdb
, or changes to the default database settings in the model
database.
Prerequisites
Perform the following tasks before you rebuild the system databases to ensure that you can restore the system databases to their current settings.
Record all server-wide configuration values.
SELECT * FROM sys.configurations;
Record all hotfixes applied to the instance of SQL Server and the current collation. You must reapply these hotfixes after rebuilding the system databases.
SELECT SERVERPROPERTY('ProductVersion ') AS ProductVersion, SERVERPROPERTY('ProductLevel') AS ProductLevel, SERVERPROPERTY('ResourceVersion') AS ResourceVersion, SERVERPROPERTY('ResourceLastUpdateDateTime') AS ResourceLastUpdateDateTime, SERVERPROPERTY('Collation') AS Collation;
Record the current location of all data and log files for the system databases. Rebuilding the system databases installs all system databases to their original location. If you have moved system database data or log files to a different location, you must move the files again.
SELECT name, physical_name AS current_file_location FROM sys.master_files WHERE database_id IN (DB_ID('master'), DB_ID('model'), DB_ID('msdb'), DB_ID('tempdb'));
Locate the current backup of the
master
,model
, andmsdb
databases.If the instance of SQL Server is configured as a replication distributor, locate the current backup of the
distribution
database.Ensure you have appropriate permissions to rebuild the system databases. To perform this operation, you must be a member of the sysadmin fixed server role. For more information, see Server-Level Roles.
Verify that copies of the
master
,model
,msdb
data and log template files exist on the local server. The default location for the template files isC:\Program Files\Microsoft SQL Server\MSSQL<xx>.MSSQLSERVER\MSSQL\Binn\Templates
(where<xx>
is the version you have installed). These files are used during the rebuild process and must be present for Setup to succeed. If they are missing, run the Repair feature of Setup, or manually copy the files from your installation media. To locate the files on the installation media, navigate to the appropriate platform directory (x86 or x64) and then navigate tosetup\sql_engine_core_inst_msi\Pfiles\SqlServr\MSSQL.X\MSSQL\Binn\Templates
.
Rebuild system databases
The following procedure rebuilds the master
, model
, msdb
, and tempdb
system databases. You can't specify the system databases to be rebuilt. For clustered instances, this procedure must be performed on the active node and the SQL Server resource in the corresponding cluster application group must be taken offline before performing the procedure.
This procedure doesn't rebuild the resource
database. See the section Rebuild the resource system database later in this article.
Rebuild system databases for an instance of SQL Server
Insert the SQL Server installation media into the disk drive, or, from a command prompt, change directories to the location of the
setup.exe
file on the local server. For SQL Server 2022 (16.x), the default location on the server isC:\Program Files\Microsoft SQL Server\160\Setup Bootstrap\SQLServer2022
.From a command prompt window, enter the following command. Square brackets are used to indicate optional parameters. Don't enter the brackets. When using a Windows operating system that has User Account Control (UAC) enabled, running Setup requires elevated privileges. The command prompt must be run as Administrator.
setup /QUIET /ACTION=REBUILDDATABASE /INSTANCENAME=InstanceName /SQLSYSADMINACCOUNTS=accounts [ /SAPWD= StrongPassword ] [ /SQLCOLLATION=CollationName ]
Parameter name Description /QUIET or /Q Specifies that Setup should run without any user interface. /ACTION=REBUILDDATABASE Specifies that Setup should recreate the system databases. /INSTANCENAME=InstanceName The name of the instance of SQL Server. For the default instance, enter MSSQLSERVER. /SQLSYSADMINACCOUNTS=accounts Specifies the Windows groups or individual accounts to add to the sysadmin fixed server role. When specifying more than one account, separate the accounts with a blank space. For example, enter BUILTIN\Administrators MyDomain\MyUser. When you are specifying an account that contains a blank space within the account name, enclose the account in double quotation marks. For example, enter NT AUTHORITY\SYSTEM. [ /SAPWD=StrongPassword ] Specifies the password for the SQL Server sa account. This parameter is required if the instance uses Mixed Authentication (SQL Server and Windows Authentication) mode.
Security note: The sa account is a well-known SQL Server account and it is often targeted by malicious users. It is critical that you use a strong password for the sa login.
Don't specify this parameter for Windows Authentication mode.[ /SQLCOLLATION=CollationName ] Specifies a new server-level collation. This parameter is optional. When not specified, the current collation of the server is used.
Important: Changing the server-level collation doesn't change the collation of existing user databases. All newly created user databases will use the new collation by default.
For more information, see Set or Change the Server Collation.[ /SQLTEMPDBFILECOUNT=NumberOfFiles ] Specifies the number of tempdb
data files. This value can be increased up to 8 or the number of cores, whichever is higher.
Default value: 8 or the number of cores, whichever is lower.[ /SQLTEMPDBFILESIZE=FileSizeInMB ] Specifies the initial size of each tempdb
data file in MB. Setup allows the size up to 1024 MB.
Default value: 8[ /SQLTEMPDBFILEGROWTH=FileSizeInMB ] Specifies the file growth increment of each tempdb
data file in MB. A value of 0 indicates that automatic growth is off and no additional space is allowed. Setup allows the size up to 1024 MB.
Default value: 64[ /SQLTEMPDBLOGFILESIZE=FileSizeInMB ] Specifies the initial size of the tempdb
log file in MB. Setup allows the size up to 1024 MB.
Default value: 8.
Allowed range: Min = 8, max = 1024.[ /SQLTEMPDBLOGFILEGROWTH=FileSizeInMB ] Specifies the file growth increment of the tempdb
log file in MB. A value of 0 indicates that automatic growth is off and no additional space is allowed. Setup allows the size up to 1024 MB.
Default value: 64
Allowed range: Min = 8, max = 1024.[ /SQLTEMPDBDIR=Directories ] Specifies the directories for tempdb
data files. When specifying more than one directory, separate the directories with a blank space. If multiple directories are specified thetempdb
data files will be spread across the directories in a round-robin fashion.
Default value: System Data Directory[ /SQLTEMPDBLOGDIR=Directory ] Specifies the directory for the tempdb
log file.
Default value: System Data DirectoryWhen Setup has completed rebuilding the system databases, it returns to the command prompt with no messages. Examine the Summary.txt log file to verify that the process completed successfully. This file is located at
C:\Program Files\Microsoft SQL Server\160\Setup Bootstrap\Logs
.The RebuildDatabase scenario deletes system databases and installs them again in a clean state. Because the setting of
tempdb
file count doesn't persist, the value of number oftempdb
files isn't known during setup. Therefore, the ebuildDatabase scenario doesn't know the count oftempdb
files to be readded. You can provide the value of the number oftempdb
files again with the SQLTEMPDBFILECOUNT parameter. If the parameter isn't provided, RebuildDatabase will add a default number oftempdb
files, which is as manytempdb
files as the CPU count or 8, whichever is lower.
Post-rebuild tasks
After rebuilding the database, you might need to perform the following additional tasks:
Restore your most recent full backups of the
master
,model
, andmsdb
databases. For more information, see Back Up and Restore of System Databases (SQL Server).Important
If you have changed the server collation, do not restore the system databases. Doing so will replace the new collation with the previous collation setting.
If a backup isn't available or if the restored backup isn't current, re-create any missing entries. For example, re-create all missing entries for your user databases, backup devices, SQL Server logins, end points, and so on. The best way to re-create entries is to run the original scripts that created them.
Important
We recommend that you secure your scripts to prevent their being altered by unauthorized by individuals.
If the instance of SQL Server is configured as a replication distributor, you must restore the
distribution
database. For more information, see Back Up and Restore Replicated Databases.Move the system databases to the locations you recorded previously. For more information, see Move System Databases.
Verify the server-wide configuration values match the values you recorded previously.
Rebuild the resource database
The following procedure rebuilds the resource
system database. When you rebuild the resource
database, all hot fixes are lost, and therefore must be reapplied.
Rebuild the resource system database
Launch the SQL Server Setup program (
setup.exe
) from the distribution media.In the left navigation area, select Maintenance, and then select Repair.
Setup support rule and file routines run to ensure that your system has prerequisites installed and that the computer passes Setup validation rules. Select OK or Install to continue.
On the Select Instance page, select the instance to repair, and then select Next.
The repair rules will run to validate the operation. To continue, select Next.
From the Ready to Repair page, select Repair. The Complete page indicates that the operation is finished.
Create a new msdb database
If the msdb
database is damaged or suspect and you don't have a backup of the msdb
database, you can create a new msdb
by using the instmsdb
script.
Warning
Rebuilding the msdb
database using the instmsdb.sql
script will eliminate all the information stored in msdb
such as jobs, alert, operators, maintenance plans, backup history, Policy-Based Management settings, Database Mail, Performance Data Warehouse, and so on.
Stop all services connecting to the Database Engine, including SQL Server Agent, SSRS, SSIS, and all applications using SQL Server as data store.
Start SQL Server from the command line using the command:
NET START MSSQLSERVER /T3608
For more information, see Start, Stop, Pause, Resume, Restart the Database Engine, SQL Server Agent, or SQL Server Browser Service. For information on Trace Flag 3608, see TF3608.
In another command line window, detach the
msdb
database by executing the following command, replacing<servername>
with the instance of SQL Server:SQLCMD -E -S<servername> -dmaster -Q"EXEC sp_detach_db msdb"
Using the Windows Explorer, rename the
msdb
database files. By default these are in the DATA subfolder for the SQL Server instance.Using SQL Server Configuration Manager, stop and restart the Database Engine service normally with no additional trace flags.
In a command prompt window, connect to SQL Server and execute the command:
SQLCMD -E -S<servername> -i"C:\Program Files\Microsoft SQL Server\MSSQLXX.INSTANCE_NAME\MSSQL\Install\instmsdb.sql" -o"C:\Program Files\Microsoft SQL Server\MSSQL16.MSSQLSERVER\MSSQL\Install\instmsdb.out"
Replace
<servername>
with the instance of the Database Engine. Use the file system path of the instance of SQL Server. Also, replaceMSSQLXX.INSTANCE_NAME
with the directory that corresponds to your version and instance.Using the Windows Notepad, open the
instmsdb.out
file and check the output for any errors.Reapply any CUs that are installed on the instance, which will upgrade your
msdb
database to the current CU level.Recreate the user content stored in the
msdb
database, such as jobs, alerts, and other items.Back up the
msdb
database.
Rebuild the tempdb database
If the tempdb
database is damaged or suspect and the database engine fails to start, you can rebuild tempdb
without the need to rebuild all system databases.
Rename the current
tempdb.mdf
andtemplog.ldf
files, if not missing.Start SQL Server from a Command Prompt by using the sqlservr application.
sqlservr -c -f -T3608 -T4022 -s <instance> -mSQLCMD
For a default instance name use
MSSQLSERVER
, for named instance useMSSQL$<instance_name>
. Trace flag 4022 disables execution of startup stored procedures. The-mSQLCMD
allows only sqlcmd.exe to connect to the server. For more information, see Other Startup Options.Note
Make sure that the command prompt window remains open after the SQL Server starts. Closing the command prompt window will terminate the process.
Connect to the server by using sqlcmd, and then use the following stored procedure to reset the status of the
tempdb
database.exec master..sp_resetstatus tempdb
Shut down the server by pressing
Ctrl
+C
in the command prompt window.Restart the SQL Server service. This creates a new set of
tempdb
database files, and recovers thetempdb
database.
Troubleshoot rebuild errors
Syntax and other run-time errors are displayed in the command prompt window. Examine the Setup statement for the following syntax errors:
Missing slash mark (
/
) in front of each parameter name.Missing equal sign (
=
) between the parameter name and the parameter value.Presence of blank spaces between the parameter name and the equal sign.
Presence of commas (
,
) or other characters that aren't specified in the syntax.
After the rebuild operation is complete, examine the SQL Server logs for any errors. The default log location is C:\Program Files\Microsoft SQL Server\160\Setup Bootstrap\Logs
. To locate the log file that contains the results of the rebuild process, change directories to the Logs folder from a command prompt, and then run findstr /s RebuildDatabase summary*.*
. This search will point you to any log files that contain the results of rebuilding system databases. Open the log files and examine them for relevant error messages.