Restore or Attach a Windows SQL Server Database Backup on a Linux Server

By:   |   Comments   |   Related: > SQL Server on Linux


Problem

Now that SQL Server is available on Linux, many companies may start to use a Linux server for testing database development due to license costs. In this tip I will show you how to move a copy of a database from Windows SQL Server to a Linux SQL Server installation.

Solution

It's a fact that companies across the globe want to reduce costs. That and the forthcoming edition of SQL Server for Linux brings us a possible scenario where non-production SQL Server databases may be running on top of Linux systems. Because of this, we must know how to move a SQL Server database from Windows to Linux.

Create a SQL Server Database Backup

The first step to copy a database to Linux is, of course, to take a backup of the database we want to move. But remember that if the database is in production you should take the backup with the COPY_ONLY option to not break the backup sequence. If you don't know about this concept I suggest you to read the SQL Server Backup Options and Commands Tutorial and the following tip COPY_ONLY Backups with SQL Server in order to know more.

Copying SQL Server Backup Files to Linux

The most common way to move files into Linux is with Secure Copy (also known as SCP). It is based on the Secure Shell (referred to as SSH) protocol. For us who are used to the Windows GUI, I suggest you use the open source program WinSCP, which can be downloaded for free at this URL: https://winscp.net/eng/download.php.

When you start WinSCP it shows a login screen like the image below, asking you for the connection details.

WinSCP Login Screen.

After successfully logging in, the program shows two panels the file and folder structure of the current machine (on the left) and the remote server (on the right). To copy a file is as easy as dragging the file from the local file system panel to the remote file system panel. I am using my home folder on the remote system to copy the backup file.

Transferring files to Linux.

Restoring the SQL Server Database on a Linux Server

Now that we have the backup file on our Linux server, it's time to restore the database. Let's check the contents of the backup file.

USE master
GO

RESTORE FILELISTONLY FROM DISK = '/home/daniel/AdventureWorks2012.bak'

As you can see on the image below, the database contains one data file and one log file named AdventureWorks2012_Data and AdventureWorks2012_Log respectively.

Checking Backup Content.

If you take a look at the PhysicalName column from the result, you will see that it is represented as a Windows path. This means that we must restore the database using the WITH MOVE option; otherwise we will get an error message telling us that the Directory lookup has failed as shown below.

If you don't specify a destination for the files, Restore will fail.

I will restore the database to the default SQL Server data location which is /var/opt/mssql/data using the WITH MOVE option.

USE master;

RESTORE DATABASE AdventureWorks2012 
FROM DISK = '/home/daniel/AdventureWorks2012.bak'
WITH MOVE 'AdventureWorks2012_Data' TO '/var/opt/mssql/data/AdventureWorks2012.mdf',
MOVE 'AdventureWorks2012_Log' TO '/var/opt/mssql/data/AdventureWorks2012.ldf', 
STATS = 10

The next is a screen capture showing that we have successfully restored the database, and in this case the database was upgraded to the latest version.

Database was successfully restored.

Attaching a SQL Server Database

To attach a database on a SQL Server instance running on Linux is not much different. After copying the mdf and ldf files to the Linux server to the SQL Server data location which is /var/opt/mssql/data we must grant ownership of the files to the SQL Server user account, usually mssql. To change ownership we must use the chown command as root.

I have copied two files of a database named DBA (DBA.mdf and DBA_log.ldf) to the location /var/opt/mssql/data. In order to change ownership of those files to the SQL Server user account I have to run the following command.

Chown mssql:mssql /var/opt/mssql/data/DBA*

The mssql:mssql on the command represents the user and group to grant ownership, the rest is the file names (notice that I have used a wildcard DBA*).

Also we need to grant read and write permissions on the files to the SQL Server user account. We do so with the chmod command.

chmod u=+rw,g=+rw,o=-rw  /var/opt/mssql/data/DBA*

The previous statement grants read and write permissions to the owner and to the group the owner belongs and removes permissions to the rest of the users.

Setting up user right assignment.

After completing the previous step I am able to attach the database the way we normally do.

USE master;

CREATE DATABASE DBA 
ON PRIMARY (FILENAME = '/var/opt/mssql/data/DBA.mdf'),
   (FILENAME = '/var/opt/mssql/data/DBA_log.ldf') 
FOR ATTACH

Screen capture showing how to attach a database.
Next Steps


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Daniel Farina Daniel Farina was born in Buenos Aires, Argentina. Self-educated, since childhood he showed a passion for learning.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips



Comments For This Article

















get free sql tips
agree to terms