As a system administrator, sometimes you might want to migrate an entire SQL instance to a new server as part of a version update or a hardware upgrade. As there is no inbuilt option to migrate an SQL instance in an MSSQL server, we have to do it manually, So let’s get started how to perform an MSSQL instance migration.
To start the migration, an SQL instance on the destination server must be created first. Make sure the destination server has enough hardware resources to accommodate the migrating instance.
The instructions for performing the manual migration process are detailed below.
1. To transfer databases (DBs), detach it first from the source server and attach it to the destination server. You can connect to the source SQL server using the MSSQL server management studio.

Then, Right click on the instance name and stop it.

Or, stop the appropriate SQL instance service from the ‘Services’ manager.

Now copy all data (.mdf) and log (.ldf) files from the SQL data folder, and move it to the destination server. For larger data, you can use any third party applications like Total commander to speed up the copying task.
Start the SQL instance once it is done.
Note: By default, the SQL data directory will be D:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA. Usually, we set SQL data directory to a non-OS drive to overcome any OS failure.
2. Once the data and log files are copied to the destination server, you need to attach it. Attaching DBs manually can be tiresome if there are hundreds of them. You can use the script below to automate it.

USE master;
GO
SET NOCOUNT ON
IF OBJECT_ID( 'tempdb.dbo.#tmp' ) IS NOT NULL DROP TABLE #tmp;
DECLARE
@SQLcmd VARCHAR(MAX)
,@DatabaseName VARCHAR(255)
,@PrevDatabaseName VARCHAR(255);
SET @SQLcmd = '';
SET @DatabaseName = ';';
SET @PrevDatabaseName = '';
CREATE TABLE #tmp (
DatabaseName SYSNAME NULL
,FileId INT NULL
,FileName VARCHAR(2000) NULL
,SQLcmd VARCHAR(MAX) NULL
);
INSERT  INTO #tmp
SELECT DISTINCT
DB_NAME(dbid) AS DatabaseName
,FileId
,FileName
,CONVERT(VARCHAR(MAX), '') AS SQLcmd
FROM master.dbo.sysaltfiles
WHERE dbid IN (
SELECT dbid FROM master.dbo.sysaltfiles
WHERE SUBSTRING(FileName, 1, 1) IN ( 'D', 'E' ) )  -- Put the appropriate drives here
--AND DATABASEPROPERTYEX(DB_NAME(dbid), 'Status') = 'ONLINE'
AND DB_NAME(dbid) NOT IN ( 'master', 'model', 'msdb', 'tempdb', 'ditribution' )
ORDER BY DatabaseName, FileId, FileName;
UPDATE #tmp SET
@SQLcmd = SQLcmd = CASE WHEN DatabaseName <> @PrevDatabaseName
THEN CONVERT(VARCHAR(200), 'exec sp_attach_db @DBName = N''' + DatabaseName + '''')
ELSE @SQLcmd
END + ',@FileName' + CONVERT(VARCHAR(10), FileId) + '=N''' + FileName + ''''
,@PrevDatabaseName = CASE WHEN DatabaseName <> @PrevDatabaseName THEN DatabaseName
ELSE @PrevDatabaseName
END
,@DatabaseName = DatabaseName
FROM #tmp;
SELECT
'USE master;' + CHAR(13) + CHAR(10) + 'GO'
SELECT
SQLcmd
FROM
( SELECT DatabaseName, MAX(SQLcmd) AS SQLcmd
FROM #tmp
GROUP BY DatabaseName
) AS SQLcmd;
--DROP TABLE #tmp
GO

Run the above script on the source server. It will create a database attach script for all DBs present on the source server. Just change the drive letters if needed. This script will search for SQL data folders on the mentioned drives.

3. Copy all the output of the above script, and execute it on the destination server. All DBs will be attached automatically as soon as the script is executed. Click on refresh button to make the newly attached DBs visible.

The transfer of all DBs from the source server to the destination server is now completed.
Note: On destination server, make sure that DB data location is same as the source server. If you want to change the DB data location on destination server, then you have to alter the entire DB attach script with new location. You can use tools like ‘Find and Replace’ to simplify the task.
4. The transfer of database logins may be carried out now. You can run the script below on source server to carry out the transfer.

USE master
GO
IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL
  DROP PROCEDURE sp_hexadecimal
GO
CREATE PROCEDURE sp_hexadecimal
    @binvalue varbinary(256),
    @hexvalue varchar (514) OUTPUT
AS
DECLARE @charvalue varchar (514)
DECLARE @i int
DECLARE @length int
DECLARE @hexstring char(16)
SELECT @charvalue = '0x'
SELECT @i = 1
SELECT @length = DATALENGTH (@binvalue)
SELECT @hexstring = '0123456789ABCDEF'
WHILE (@i <= @length)
BEGIN
  DECLARE @tempint int
  DECLARE @firstint int
  DECLARE @secondint int
  SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1))
  SELECT @firstint = FLOOR(@tempint/16)
  SELECT @secondint = @tempint - (@firstint*16)
  SELECT @charvalue = @charvalue +
    SUBSTRING(@hexstring, @firstint+1, 1) +
    SUBSTRING(@hexstring, @secondint+1, 1)
  SELECT @i = @i + 1
END
SELECT @hexvalue = @charvalue
GO
IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL
  DROP PROCEDURE sp_help_revlogin
GO
CREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS
DECLARE @name sysname
DECLARE @type varchar (1)
DECLARE @hasaccess int
DECLARE @denylogin int
DECLARE @is_disabled int
DECLARE @PWD_varbinary  varbinary (256)
DECLARE @PWD_string  varchar (514)
DECLARE @SID_varbinary varbinary (85)
DECLARE @SID_string varchar (514)
DECLARE @tmpstr  varchar (1024)
DECLARE @is_policy_checked varchar (3)
DECLARE @is_expiration_checked varchar (3)
DECLARE @defaultdb sysname
IF (@login_name IS NULL)
  DECLARE login_curs CURSOR FOR
      SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
      ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name <> 'sa'
ELSE
  DECLARE login_curs CURSOR FOR
      SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
      ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name = @login_name
OPEN login_curs
FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin
IF (@@fetch_status = -1)
BEGIN
  PRINT 'No login(s) found.'
  CLOSE login_curs
  DEALLOCATE login_curs
  RETURN -1
END
SET @tmpstr = '/* sp_help_revlogin script '
PRINT @tmpstr
SET @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */'
PRINT @tmpstr
PRINT ''
WHILE (@@fetch_status <> -1)
BEGIN
  IF (@@fetch_status <> -2)
  BEGIN
    PRINT ''
    SET @tmpstr = '-- Login: ' + @name
    PRINT @tmpstr
    IF (@type IN ( 'G', 'U'))
    BEGIN -- NT authenticated account/group
      SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']'
    END
    ELSE BEGIN -- SQL Server authentication
        -- obtain password and sid
            SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, 'PasswordHash' ) AS varbinary (256) )
        EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT
        EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT
        -- obtain password policy state
        SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name
        SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name
            SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string + ' HASHED, SID = ' + @SID_string + ', DEFAULT_DATABASE = [' + @defaultdb + ']'
        IF ( @is_policy_checked IS NOT NULL )
        BEGIN
          SET @tmpstr = @tmpstr + ', CHECK_POLICY = ' + @is_policy_checked
        END
        IF ( @is_expiration_checked IS NOT NULL )
        BEGIN
          SET @tmpstr = @tmpstr + ', CHECK_EXPIRATION = ' + @is_expiration_checked
        END
    END
    IF (@denylogin = 1)
    BEGIN -- login is denied access
      SET @tmpstr = @tmpstr + '; DENY CONNECT SQL TO ' + QUOTENAME( @name )
    END
    ELSE IF (@hasaccess = 0)
    BEGIN -- login exists but does not have access
      SET @tmpstr = @tmpstr + '; REVOKE CONNECT SQL TO ' + QUOTENAME( @name )
    END
    IF (@is_disabled = 1)
    BEGIN -- login is disabled
      SET @tmpstr = @tmpstr + '; ALTER LOGIN ' + QUOTENAME( @name ) + ' DISABLE'
    END
    PRINT @tmpstr
  END
  FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin
   END
CLOSE login_curs
DEALLOCATE login_curs
RETURN 0
GO

The above script will create two stored procedures named sp_hexadecimal and sp_help_revlogin under the master database.

5. To generate the login script , execute the ‘sp_help_revlogin’ stored procedure. To do that, open a new query window and run:

EXEC sp_help_revlogin

This will generate a login script. Copy it.
6. To create the logins on destination server, execute the login script (output of step 5) on the destination server. This login script creates the logins that have the original Security Identifier (SID), and the original password.
It’s done! You have now successfully executed instance migration in MSSQL.
 
Thanks for dropping by. Ready for the next blog?
https://dev.sysally.com/blog/cpanel-solo-new-offering-cpanel
 

Get new insights right to your inbox

How can our experts help you?

Schedule your consultation

You may also like

  • By admin
  • in DevOps

Agile vs DevOps: What’s the difference

  • Nov 18, 2022 .
  • 9 min min
Read More
  • By admin
  • in DevOps

DevOps as a Service: All You Should Know

  • Aug 9, 2022 .
  • 9 min min
Read More
  • By admin
  • in Containerization

Containerization VS Virtualization: Understanding the Differences

  • Aug 4, 2022 .
  • 8 min min
Read More

Be in the know

Techno tips served hot! Subscribe now and stay atop.