Error while moving model and msdb system databases.

  • Hi,

    I am using SQL Server 2008 and I have three SQL Server instances installed and I am trying to move the model and msdb system databases of only one instance.

    I have added -T3608;-m;-c startup parameters from configuration manager for that specific instance and I have restarted the service.

    I have followed the same steps as described in the following link : http://support.microsoft.com/default.aspx?scid=kb;en-us;224071

    I am getting these error msgs whenever I try to attach and detach the model and msdb databases using sp_detach 'model' and sp_attach_db <<path to mdf and ldf>>.

    “Cannot detach an opened database when the server is in minimally configured mode” when trying to sp_detach_db ‘model’.

    *** and the database instance service is getting stopped automatically and soon after that I am getting the following error msg if I try to execute sp_attach_db .

    "A transport-level error has occurred when receiving results from the server. (provider: Shared Memory Provider, error: 0 - The pipe has been ended.)"

    I don't know why the database instance service is getting stopped automatically.

    I have checked everything I could ie TCP/IP (enabled),named pipes(enabled),... but nothing worked.

    Do I need to make any other settings before starting the process?

    Please reply to this post as early as possible. Thanks in advance.

    Abdul Samad

  • 1st, using the following script to move model and msdb to destination:

    --- Moving msdb

    alter database msdb modify file (name = MSDBData, filename = 'X:\MSSQL\DATA\MSDBData.mdf')

    go

    alter database msdb modify file (name = MSDBLog, filename = 'X:\MSSQL\Log\MSDBLog.ldf')

    go

    --- Then, manually copy the files to the destination

    --- Moving model

    alter database model modify file (name = modeldev, filename = 'X:\MSSQL\DATA\model.mdf')

    go

    alter database model modify file (name = modellog, filename = 'X:\MSSQL\Log\modellog.ldf')

    go

    --- Then, manually copy the files to the destination

    2nd, stop SQL Server

    3rd, manually copy model and msdb files to destination

    4th, restart SQL server

    5th, DONE. (to verify, select * from master.sys.master_files)

  • Abdul

    as already stated you do not need to put the SQL server instance into single user mode to modify the file paths for model and msdb databases. Also, do not be tempted to change the filenames either!!

    -----------------------------------------------------------------------------------------------------------

    "Ya can't make an omelette without breaking just a few eggs" 😉

  • Thanks a lot "Wildcat" for taking your precious time out and replying to my post , the method you have suggested is just awesome and the easiest one. I thought we can move only tempdb database using that method but it worked for msdb and model database too;

    it has resolved my problem of moving msdb and model databases.

    Thanks again.

  • You may want to bookmark the following link for future reference

    http://msdn.microsoft.com/en-us/library/ms345408.aspx

    -----------------------------------------------------------------------------------------------------------

    "Ya can't make an omelette without breaking just a few eggs" 😉

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply