Linux:migration


Flollowing are steps taken for migrating Database from Windows to Linux:

  1. Open the SQL Server from Windows

Creating Database 

CREATE DATABASE MigrationTest
USE MigrationTest

--Creating Table
Create table Employee(id int identity, city varchar(20))
insert into Employee values('Pune'),('Mumbai')
Select * from Employee

--Creating Login and assigning some server roles

USE [master]
GO
CREATE LOGIN [anurag] WITH PASSWORD=N'anurag@123', DEFAULT_DATABASE=[master], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF
GO


ALTER SERVER ROLE [dbcreator] ADD MEMBER [anurag]
GO
ALTER SERVER ROLE [diskadmin] ADD MEMBER [anurag]
GO

--Mapping user to login and giving select permission
USE [MigrationTest]
GO
CREATE USER [anurag] FOR LOGIN [anurag]
GO
GRANT SELECT ON EMPLOYEE TO ANURAG

Check table by selecting:


Taking Database Backup:

BACKUP DATABASE MigrationTest to DISK='MigrationTest.bak'

--Transfer Backup file in linux using WinScp
Get ip address of linux using ifconfig & connect using winscp


Transfer & restore backup

Here I have created a folder under var named backup and uploaded a backup file.


RESTORE FILELISTONLY FROM DISK=N'/var/backup/MigrationTest.bak'

USE [master]
RESTORE DATABASE [MigrationTest] FROM  DISK = N'/var/backup/MigrationTest.bak' WITH  FILE = 1,  
MOVE N'MigrationTest' TO N'/var/opt/mssql/data/MigrationTest.mdf',  
MOVE N'MigrationTest_log' TO N'/var/opt/mssql/data/MigrationTest_log.ldf',  
NOUNLOAD,  STATS = 5

GO

After restoring database checking if table, user are reflected or not:


As no login is reflected so we have to map it:

 Mapping Logins:


Creating login by mapping it so same sid is attached with previous passwords, permissions:
Here is good link to get description about this:


-- Revlogin Script to get login names:

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

Run this stored procedure on primary server:

After running this create login on linux sql server check connection with same password:

--login is connected successfully 

--check if table has selwct access by quering.

Name

Azure Backup Database Clustering Crash Dumps DBCC Deadlock Link Server Log Shipping Maintenance Migration Mirroring Monitoring Performance Tuning Permissions Post Installations Prerequisites Replication Restore Database SQL Installations SQL on Linux SQL Uninstallations SSIS T-SQL Windows Server
false
ltr
item
hybriddba.blogspot.com: Linux:migration
Linux:migration
https://blogger.googleusercontent.com/img/b/R29vZ2xl/AVvXsEhBQRcKYyic8Jum97EIyLwati-D7EYD4zv60MxEkfpDkZXPUwx2Dij4FNoyisEv4idmJj7agB_6HhOZQPwZWrkhadKPcj6wWXAUEc2xRLXpB1v8n7rH4ZeR9y2eCmL4_AxX60qu5t1jjw2u/s1600/1579484445437347-0.png
https://blogger.googleusercontent.com/img/b/R29vZ2xl/AVvXsEhBQRcKYyic8Jum97EIyLwati-D7EYD4zv60MxEkfpDkZXPUwx2Dij4FNoyisEv4idmJj7agB_6HhOZQPwZWrkhadKPcj6wWXAUEc2xRLXpB1v8n7rH4ZeR9y2eCmL4_AxX60qu5t1jjw2u/s72-c/1579484445437347-0.png
hybriddba.blogspot.com
https://hybriddba.blogspot.com/2019/06/linuxmigration.html
https://hybriddba.blogspot.com/
https://hybriddba.blogspot.com/
https://hybriddba.blogspot.com/2019/06/linuxmigration.html
true
7679493960263860249
UTF-8
Not found any posts Not found any related posts VIEW ALL Readmore Reply Cancel reply Delete By Home PAGES POSTS View All RECOMMENDED FOR YOU Tag ARCHIVE SEARCH ALL POSTS Not found any post match with your request Back Home Contents See also related Sunday Monday Tuesday Wednesday Thursday Friday Saturday Sun Mon Tue Wed Thu Fri Sat January February March April May June July August September October November December Jan Feb Mar Apr May Jun Jul Aug Sep Oct Nov Dec just now 1 minute ago $$1$$ minutes ago 1 hour ago $$1$$ hours ago Yesterday $$1$$ days ago $$1$$ weeks ago more than 5 weeks ago Followers Follow THIS CONTENT IS PREMIUM Please share to unlock Copy All Code Select All Code All codes were copied to your clipboard Can not copy the codes / texts, please press [CTRL]+[C] (or CMD+C with Mac) to copy