How to Import and Export Unstructured Data in SQL Server - The IMAGE Datatype

Importing and exporting unstructured data from a database is a common practice, especially in large applications. SQL Server 2008 introduced the FILESTREAM feature that allows storing unstructured data (i.e. music, video, documents, etc.) onto the NTFS file system and manipulating it via the Database Engine. SQL Server 2012 introduced FileTables which is an enhancement to FILESTREAM.

With this post I am starting a series of articles that will deal with the topic of storing, manipulating and extracting unstructured data from SQL Server.

In this article we are going to see how it is possible to import and export binary objects in SQL Server 2005. Instead of saying more I would just like to show you by example how you can do this.

For this example, consider that we have the following two objects:



Figure 1: The two sample files for the BLOBs example.




















Let's take a closer look at the files just for checking out their content:
Figure 2: Content of SampleTextFile.txt

























Figure 3: Content of SampleImage.png






















Now let's store these two files in a SQL Server table.

USE master;
GO

--Create test database
CREATE DATABASE [BinaryFilesDB];
GO

--Use test database
USE [BinaryFilesDB];
GO

--Create table that will be hosting the files
CREATE TABLE [dbo].[tblFiles](
[fileID] [bigint] IDENTITY(1,1),
[fileName] [nvarchar](255) NULL,
[binFile] [image] NOT NULL);
GO

--
--Import SampleTextFile.txt
--
INSERT INTO dbo.tblFiles
           ([fileName],[binFile])
VALUES     ('SampleTextFile.txt',(SELECT * FROM   OPENROWSET(BULK 'c:\testing\SampleTextFile.txt',SINGLE_BLOB) AS x))
GO
--
--Import SampleImage.png
--
INSERT INTO dbo.tblFiles
           ([fileName],[binFile])
VALUES     ('SampleImage.png',(SELECT * FROM   OPENROWSET(BULK 'c:\testing\SampleImage.png',SINGLE_BLOB) AS x))
GO

Let's check the contents of "tblFiles" table:
Figure 4: Contents of the table after importing the binary files.








Let's rename the files, just for performing a minor modification:

--Rename files
UPDATE tblFiles
SET fileName='SampleTextFileModified.txt'
WHERE filename='SampleTextFile.txt';
GO

UPDATE tblFiles
SET fileName='SampleImageModified.png'
WHERE filename='SampleImage.png';
GO

Let's check the table contents again:
Figure 5: Renamed contents of table "tblFiles"







Now let's produce the export statements:

SELECT
'bcp "select binFile from BinaryFilesDB.dbo.tblFiles where fileid=' + cast (fileID as varchar(50)) + '" queryout "c:\testing\'+[filename]
+'" -f bcp.fmt -S .\SQL2K14CTP2 -T' as RunTheseOnCommandPrompt
FROM BinaryFilesDB.dbo.tblFiles;
GO

Some notes on the above T-SQL statement: - SQL2K14CTP2 is the named instance of my SQL Server
- Also note that I am using Trusted (-T) connection for my generated bcp commands
- If you want to use username/password instead of a Trusted connection replace "-T" with -U [username] -P [password]
- You can download the bcp.fmt format file from here.

Figure 6: Generated statements for exporting the binary files.










Now let's run the two bcp commands on the command prompt:
Figure 7: Executing the bcp commands for exporting the binary files.


















Also, let's check the contents of the "c:\testing" directory:
Figure 8: Binary files successfully exported from SQL Server.











As you can see, the two renamed files were successfully exported and have the exact same size as the original ones! I hope you enjoyed the article! Until next time!

--
My Latest Projects:

Labels: , ,