Introduction
This article is intended primarily for intermediate to advanced SSIS (SQL Server Integration Services) users who are familiar with SQL Server Business Intelligence. Basic understanding of script task, Execute Sql Task, parameters and variables are required, as it is not exactly a tutorial, but a description of the implementation of exporting the database table objects to Excel Objects through SSIS without the need of any templates and much of programming.This package will help to migrate data in a simple and efficient way. This package could also be useful to the users of SQL Server 2008 database, which could help in replacing the deprecated sp_makewebtask feature for exporting the data to excel.
The Goal of this article is to help the users by providing the concept to create a Excel file with unlimited sheets with all the data from the SQL Sever database eliminating the need of SSIS data conversion tasks, mapping and predefined column names, data types and etc. The same concept of developing generic packages can be applied similarly when migrating SQL Server data to different databases like Oracle, Teradata, MS-Access and etc using the connection manager with related data source providers can be achieved through the SSIS ETL Tool.
This Generic DTSX package is basically to demonstrate a method of data migration to export SQL Server database tables to Excel file with multiple sheets. After reading many blogs about people having problems in generating excel files and sheets dynamically from SQL Server 2000/2005 through SSIS (SQL Server Integration Services). Here is the simple DTSX package which creates a excel file on the fly and dumps the data on the sheets.
Currently Most of the Microsoft Dynamics ERP software products like (Navision, Axapta, Great Plains, Solomon, Concorde, Point of Sale, Retail Management System, Customer Relationship Management and etc) are also using the SQL Server and Excel for data migration and reporting purpose.
Little bit of tweaks in the below code in the tasks could help many users to achieve their goals in a easiest way.
Below is the demonstration of the steps to achieve this.
The dtsx package should look like the above Image. The package is developed using Visual Studio 2005.
Change the database connection to SQL Server 2000/2005 and point to the database which you want to export (currently it is pointed to master database). Change the Variable DestExcelFilePath
Value from 'C:\SSIS' for creating a file at the desired location.
Note: This package should work properly if all the Table names and Column names in the database are followed as per the microsoft naming standards.
Background
Excel file treats each sheet as a table.Excel-95/2003 generates only 65335 rows for sheet and 255 sheets maximum if its Excel-95, There is no rows or sheets limitation if you are using Excel 2007 and above. There are certain limitations to Excel previous versions. Read online documentation for more information.
Following are few links on Excel differences and comparisons.
http://www.add-ins.com/Excel%202003%20versus%202007.htm
http://technet.microsoft.com/en-us/library/cc179105(office.12).aspx
The above package uses the SQL Server OPENROWSET
Object for data migration. For more information on the
OPENROWSET
functionality and its options refer online documentation at the following link http://msdn.microsoft.com/en-us/library/aa276850(v=sql.80).aspx
Explanation and use of OPENROWSET
, SP_SERVEROPTION
, SP_MAKEWEBTASK and server options like 'DATA ACCESS
','SHOW ADVANCED OPTIONS
', 'AD HOC DISTRIBUTED QUERIES
' is out of scope of this article.
Using the Code
These options need to be configured 'Show Advanced Options' and 'Ad Hoc Distributed Queries' on the SQL Server before running the package. The package will fail without these Options. And importantly the database login should have admin privileges to execute the package tasks successfully. If you want to run this code, then better check with your DBA's regarding permissions you require.
SP_CONFIGURE 'Show Advanced Options', 1
GO
RECONFIGURE
GO
SP_CONFIGURE 'Ad Hoc Distributed Queries', 1
GO
RECONFIGURE
GO
[Get List of Tables to Process] Execute SQL Task: The query is to retrieve all the table names which are less then 65335 rows. ( Customize this query as per your requirement.)
DECLARE @Server varchar(50)
SET @Server = @@SERVERNAME
EXEC sp_serveroption @Server,'DATA ACCESS','TRUE'
SELECT [TableName] = so.name
FROM sysobjects so, sysindexes si
WHERE so.xtype = 'U' AND si.id = OBJECT_ID(so.name)
AND si.rows < 65335
GROUP BY so.name
ORDER BY 1 DESC
[Excel Script Generator] Execute SQLTask:The query in this task builds the table structure with the data types required for the Excel.(Most of the SQL data types have been handled here. If you want add any other specific data type or a different database then you need to modify this.)
DECLARE @vsTableName VARCHAR(100)
SET @vsTableName =?
DECLARE @vsSQL VARCHAR(8000)
BEGIN
SELECT @vsSQL = 'CREATE TABLE ' + '`' + @vsTableName + '`' + CHAR(10) + '(' + CHAR(10)
SELECT @vsSQL = @vsSQL + '[' + sc.Name + '] ' +
CASE WHEN st.Name IN ('nvarchar','ntext','text','varchar','varchar','char','nchar','xml','uniqueidentifier') THEN 'LongText'
WHEN st.Name IN ('tinyint','int','smallint','bigint','float','numeric','decimal','money','smallmoney','bit') THEN 'Long'
WHEN st.Name IN ('date','datetime','timestamp') THEN 'datetime'
ELSE ' ' END + ',' + CHAR(10)
FROM sysobjects so
JOIN syscolumns sc ON sc.id = so.id
JOIN systypes st ON st.xusertype = sc.xusertype
WHERE so.name = @vsTableName
AND st.Name not in ( 'image','sysname','binary','varbinary','xml','uniqueidentifier')
ORDER BY
sc.ColID
SELECT SUBSTRING(@vsSQL,1,LEN(@vsSQL) - 2) + CHAR(10) + ')' AS ExcelTableName
END
[Create Tables in Excel] Execute SQLTask: The create table script query from the above task is passed to this task, which is executed in the Excel file with the Excel Connection Manager for creating sheets with the table structure and data types required for the Excel. The destination file could be found with the Name (DynamicExcelFileDDMMYYYY.xls). Basically this task is the key to create all the sheets in the excel destination file.
[Get Column Names] Execute SQLTask: The task builds the column names and passes it to the below [Insert Script Generation] Script Task which is used in the query with OPENROWSET
.
DECLARE @SRCOBJECT varchar(8000)
SET @SRCOBJECT=?
DECLARE @SRCOBJECT1 varchar(8000)
SET @SRCOBJECT1 = SubString(@SRCOBJECT,CHARINDEX ('(',@SRCOBJECT)+ 1 , CHARINDEX (')',@SRCOBJECT) - 1)
SET @SRCOBJECT1 = Replace(@SRCOBJECT1,'LongText','')
SET @SRCOBJECT1 = Replace(@SRCOBJECT1 ,'Long','')
SET @SRCOBJECT1 = Replace(@SRCOBJECT1,'DateTime','')
SET @SRCOBJECT1= Replace(@SRCOBJECT1,')','')
SET @SRCOBJECT1 = Replace(@SRCOBJECT1,'`','')
SELECT @SRCOBJECT1
[Insert Script Generation] ScriptTask: This script task code in vb.net is to build a Query using SQL Server OPENROWSET
function which finally inserts the data into the ExcelSheets. The query is passed to the Execute SQL Task through a variable and is executed on the Excel file with the Excel Connection Manager.
Imports System
Imports System.Data
Imports System.Math
Imports Microsoft.SqlServer.Dts.Runtime
Public Class ScriptMain
Public Sub Main()
Dim excelFilePath As String = CStr(Dts.Variables("User::DestExcelFilePath").Value) + CStr(Dts.Variables("DestExcelFileName").Value)
Dim TableName, ExcelTable As String
TableName = CStr(Dts.Variables("User::ExcelTable").Value)
If TableName.Length > 30 Then
ExcelTable = Strings.Left(TableName, 31)
Else
ExcelTable = TableName
End If
Dim ColumnNames As String = CStr(Dts.Variables("User::ExcelColumns").Value)
Dim strCn As String = " Insert into OPENROWSET('Microsoft.Jet.OLEDB.4.0'," & _
"'Excel 8.0;Database=" + excelFilePath + "','SELECT " + ColumnNames + " FROM [" + ExcelTable + "$]') SELECT " + ColumnNames + " FROM [" + TableName + "]"
Dts.Variables("User::InsertScripter").Value = strCn
Dts.TaskResult = Dts.Results.Success
End Sub
End Class
Conclusion
The above mentioned demonstration of steps determine that excel file with multiple sheets along with data migration from SQL Server can be dynamically created using SSIS.
Hence it can be concluded that exporting the database table objects to a Excel file with multiple sheets is achieved through SSIS without the need of any templates, DLL's and much of programming.
This Article is basically intended to demonstrate the concept of developing a generic package to create sheets and table structures in a excel file with SSIS and to understand the excel functionalities. The same concept can be applied similarly when migrating SQL Server data to different databases. Its not a good Idea to export a huge database with the above package where it might end up using the system memory and other resources.
Since the Web Assistant features like SP_MAKEWEBTASK
which help in exporting the data objects to html, excel, word, etc are no longer available in SQL Server 2008. This package could also be useful to the users of SQL Server 2008 database, which could help in replacing the deprecated sp_makewebtask for exporting the data to excel file.
There are many articles on creating & handling excel files including formatting the cells, inserting formulas and manipulating the excel objects which can be achieved through various programming languages. But this article is intended for the SQL Server Integration Services users who are aware of its benefits and limitations.
The above image is provided as a sample to show the excel file created through this package.
Hope this article will serve the purpose. Any suggestions or corrections are most welcome.
References
http://msdn.microsoft.com/en-us/library/aa276850(v=sql.80).aspx
http://www.add-ins.com/Excel%202003%20versus%202007.htm
http://technet.microsoft.com/en-us/library/cc179105(office.12).aspx
Points of Interest
Reverse Engineering, Up-gradations, Conversions, Integrations and Data migration.
Have loads of real time experience on million dollar Banking and Financial data migration projects.
History
Last Updated on 16 Th Jan 2012.