Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server - Linux
SQL Server's backup and restore feature is the recommended way to migrate a database from SQL Server on Windows to SQL Server on Linux. In this tutorial, you walk through the steps required to move a database to Linux with backup and restore techniques.
You can also create a SQL Server Always On Availability Group to migrate a SQL Server database from Windows to Linux. See sql-server-linux-availability-group-cross-platform.
The following prerequisites are required to complete this tutorial:
On a Windows machine:
On a Linux machine:
There are several ways to create a backup file of a database on Windows. The following steps use SQL Server Management Studio (SSMS).
Start SQL Server Management Studio on your Windows machine.
In the connection dialog, enter localhost.
In Object Explorer, expand Databases.
Right-click your target database, select Tasks, and then select Back Up....
In the Backup Up Database dialog, verify that Backup type is Full and Back up to is Disk. Note name and location of the file. For example, a database named YourDB
on SQL Server 2019 (15.x) has a default backup path of C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\YourDB.bak
.
Select OK to back up your database.
Another option is to run a Transact-SQL query to create the backup file. The following Transact-SQL command performs the same actions as the previous steps for a database called YourDB
:
BACKUP DATABASE [YourDB]
TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\YourDB.bak'
WITH NOFORMAT, NOINIT, NAME = N'YourDB-Full Database Backup', SKIP, NOREWIND, NOUNLOAD, STATS = 10;
GO
To restore the database, you must first transfer the backup file from the Windows machine to the target Linux machine. In this tutorial, we move the file to Linux from a bash shell (terminal window) running on Windows.
Install a bash shell on your Windows machine that supports the scp (secure copy) and ssh (remote sign in) commands. Two examples include:
Open a bash session on Windows.
In your bash session, navigate to the directory containing your backup file. For example:
cd 'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\'
Use the scp command to transfer the file to the target Linux machine. The following example transfers YourDB.bak
to the home directory of user1
on the Linux server with an IP address of 192.168.2.9:
scp YourDB.bak user1@192.168.2.9:./
Here's the expected output:
The authenticity of host 192.168.2.9(192.168.2.9)' can't be established.
ECDSA key fingerprint is SHA256: aB1cD2eF-3gH4iJ5kL6-mN7oP8qR=
Are you sure you want to continue connecting (yes/no)? yes
Warning: Permanently added '192.168.2.9' (ECDSA) to the list of known hosts.
Password:
YourDB.bak 100% 8960KB 7.4MB/s 00:01
Tip
There are alternatives to using scp for file transfer. One is to use Samba to configure an SMB network share between Windows and Linux. For a walkthrough on Ubuntu, see Samba as a file server. Once established, you can access it as a network file share from Windows, such as \\machinenameorip\share
.
At this point, the backup file is on your Linux server in your user's home directory. Before restoring the database to SQL Server, you must place the backup in a subdirectory of /var/opt/mssql
, as this is owned by the user mssql
and group mssql
. If you're looking to change the default backup location, see the Configure with mssql-conf article.
In the same Windows bash session, connect remotely to your target Linux machine with ssh. The following example connects to the Linux machine 192.168.2.9
as user user1
.
ssh user1@192.168.2.9
You're now running commands on the remote Linux server.
Enter super user mode.
sudo su
Create a new backup directory. The -p
parameter does nothing if the directory already exists.
mkdir -p /var/opt/mssql/backup
Move the backup file to that directory. In the following example, the backup file resides in the home directory of user1
. Change the command to match the location and file name of your backup file.
mv /home/user1/YourDB.bak /var/opt/mssql/backup/
Exit super user mode.
exit
To restore the database backup, you can use the RESTORE DATABASE
Transact-SQL (TQL) command.
The following steps use the sqlcmd tool. If you haven't installed SQL Server tools, see Install the SQL Server command-line tools sqlcmd and bcp on Linux.
In the same terminal, launch sqlcmd. The following example connects to the local SQL Server instance with the sa
account. Enter the password when prompted, or specify the password by adding the -P
parameter.
sqlcmd -S localhost -U sa
At the >1
prompt, enter the following RESTORE DATABASE
command, pressing ENTER after each line (you can't copy and paste the entire multi-line command at once). Replace all occurrences of YourDB
with the name of your database.
RESTORE DATABASE YourDB FROM DISK = '/var/opt/mssql/backup/YourDB.bak'
WITH MOVE 'YourDB' TO '/var/opt/mssql/data/YourDB.mdf',
MOVE 'YourDB_Log' TO '/var/opt/mssql/data/YourDB_Log.ldf';
GO
You should get a message the database is successfully restored.
RESTORE DATABASE
might return an error like the following example:
File 'YourDB_Product' cannot be restored to 'Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB_Product.ndf'. Use WITH MOVE to identify a valid location for the file.
Msg 5133, Level 16, State 1, Server servername, Line 1
Directory lookup for the file "Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB_Product.ndf" failed with the operating system error 2(The system cannot find the file specified.).
In this case, the database contains secondary files. If these files aren't specified in the MOVE
clause of RESTORE DATABASE
, the restore procedure tries to create them in the same path as the original server.
You can list all files included in the backup:
RESTORE FILELISTONLY FROM DISK = '/var/opt/mssql/backup/YourDB.bak';
GO
You should get a list like the following example (listing only the two first columns):
LogicalName PhysicalName ..............
------------------- ---------------------------------------------------------------------------- ---------------
YourDB Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB.mdf ..............
YourDB_Product Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB_Product.ndf ..............
YourDB_Customer Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB_Customer.ndf ..............
YourDB_log Z:\Microsoft SQL Server\MSSQL15.GLOBAL\MSSQL\Data\YourDB\YourDB_Log.ldf ..............
You can use this list to create MOVE
clauses for the extra files. In this example, the RESTORE DATABASE
is:
RESTORE DATABASE YourDB FROM DISK = '/var/opt/mssql/backup/YourDB.bak'
WITH MOVE 'YourDB' TO '/var/opt/mssql/data/YourDB.mdf',
MOVE 'YourDB_Product' TO '/var/opt/mssql/data/YourDB_Product.ndf',
MOVE 'YourDB_Customer' TO '/var/opt/mssql/data/YourDB_Customer.ndf',
MOVE 'YourDB_Log' TO '/var/opt/mssql/data/YourDB_Log.ldf';
GO
Verify the restoration by listing all of the databases on the server. The restored database should be listed.
SELECT name
FROM sys.databases;
GO
Run other queries on your migrated database. The following command switches context to the YourDB
database and selects rows from one of its tables.
USE YourDB;
SELECT *
FROM YourTable;
GO
When you're done using sqlcmd, type exit
.
When you're done working in the remote ssh session, type exit
again.
In this tutorial, you learned how to back up a database on Windows and move it to a Linux server running SQL Server. You learned how to:
RESTORE DATABASE
commandNext, explore other migration scenarios for SQL Server on Linux.
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Module
Migrate SQL Server workloads to Azure Virtual Machine - Training
Discover the tools and features available to migrate SQL workloads from on-premises to Azure Virtual Machines (VMs), including the Azure SQL Migration extension for Azure Data Studio and Data Migration Assistant.
Certification
Microsoft Certified: Azure Database Administrator Associate - Certifications
Administer an SQL Server database infrastructure for cloud, on-premises and hybrid relational databases using the Microsoft PaaS relational database offerings.
Documentation
Migrate Databases to SQL Server on Linux - SQL Server
This article describes the different options for migrating databases and data to SQL Server on Linux.
New to Linux Resources for SQL Users - SQL Server
Resources and guidance for SQL Server users who are new to Linux.
Back up and Restore SQL Server Databases on Linux - SQL Server
Learn how to back up and restore SQL Server databases on Linux. Also learn how to back up and restore with SQL Server Management Studio (SSMS).