How to Load Excel File Name and Sheet Name with Data to SQL Server in SSIS Package - SSIS Tutorial

Scenario: Download Script

You need to load Excel file/s with single or multiple sheets to SQL Server Table. As you will loading the records on daily basis, you would like to keep the information which records are loading from which Excel file and Sheet. You need to create an SSIS Package that should be able to load data from Single/Multiple Excel files with single/Multiple Sheets and also log Excel file and Excel Sheet in table.

Here are my couple of Excel sample files with single and multiple Sheets.
How to load Excel files with single or multiple sheets to SQL Server Table with File Name and Sheet Name in SSIS Package by using Script Task

Solution:

I am going to create dbo.Customer Table to load these Excel Files data. As you can see the excel sheets, I have id, name and dob columns. The table dbo.Customer is going to have these columns and also FileName and SheetName so we can save Excel file name and Sheet Name from which data is loaded.

Create table dbo.Customer(
id int,
name VARCHAR(100),
dob date,
FileName VARCHAR(100),
SheetName VARCHAR(100))



Step 1: Create Variable in SSIS to Make your SSIS Package Dynamic
Create below variables in your SSIS Package
FolderPath: In this variable you will save the path from where you would like to read Excel Files
SchemaName: Schema of your Destination Table
TableName: Table in which you want to load the data

Create variables in SSIS Package to Save Excel File Name and Sheet Name with Data in SQL Server Table



Step 2: Create ADO.NET Connection in SSIS Package to use in Script Task
Create ADO.NET Connection Manager so we can use in Script Task to Load data from Excel Sheets to SQL Server Table.

Create ADO.NET Connection in SSIS Package to use in Script Task to Load Excel Data with File Name and Sheet Name


Step3: Add Variables to Script Task to use from SSIS Package
Bring the Script Task on Control Flow Pane in SSIS Package and open by double clicking Check-box in front of variable to add to Script Task.
How to use variables in Script Task in SSIS Package to Load Excel Files Data with File Name and Excel Sheet


Step 4: Add Script to Script task Editor in SSIS To load Excel Data with File Name and Sheet Name
Click Edit Button and it will open Script Task Editor.
Under #region Namespaces, I have added below code
using System.IO;
using System.Data.OleDb;
using System.Data.SqlClient;


Under public void Main() { 
I have added below code. 

            string FolderPath = Dts.Variables["User::FolderPath"].Value.ToString();
            string TableName = Dts.Variables["User::TableName"].Value.ToString();
            string SchemaName = Dts.Variables["User::SchemaName"].Value.ToString();
            
            var directory = new DirectoryInfo(FolderPath);
            FileInfo[] files = directory.GetFiles();

            //Declare and initilize variables
            string fileFullPath = "";
            SqlConnection myADONETConnection = new SqlConnection();
            myADONETConnection = (SqlConnection)(Dts.Connections["DBConn"].AcquireConnection(Dts.Transaction) as SqlConnection);

            //Get one Book(Excel file at a time)
            foreach (FileInfo file in files)
            {
                fileFullPath = FolderPath + "\\" + file.Name;

                string filename = "";
                filename = file.Name;

                //Create Excel Connection
                string ConStr;
                string HDR;
                HDR = "YES";
                ConStr = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=" + fileFullPath + ";Extended Properties=\"Excel 12.0;HDR=" + HDR + ";IMEX=0\"";
                OleDbConnection cnn = new OleDbConnection(ConStr);

                //Get Sheet Name
                cnn.Open();
                DataTable dtSheet = cnn.GetOleDbSchemaTable(OleDbSchemaGuid.Tables, null);
                string sheetname;
                sheetname = "";
                //Only read data from provided SheetNumber
                
                foreach (DataRow drSheet in dtSheet.Rows)
                {
                   
                        if (drSheet["TABLE_NAME"].ToString().Contains("$"))
                        {
                            sheetname = drSheet["TABLE_NAME"].ToString();
                           // MessageBox.Show(sheetname);
                        
                            //Load the DataTable with Sheet Data so we can get the column header
                            OleDbCommand oconn = new OleDbCommand("select top 1 * from [" + sheetname + "]", cnn);
                            OleDbDataAdapter adp = new OleDbDataAdapter(oconn);
                            DataTable dt = new DataTable();
                            adp.Fill(dt);
                            cnn.Close();

                            //Prepare Header columns list so we can run against Database to get matching columns for a table.
                            string ExcelHeaderColumn = "";
                            string SQLQueryToGetMatchingColumn = "";
                            for (int i = 0; i < dt.Columns.Count; i++)
                            {
                                if (i != dt.Columns.Count - 1)
                           ExcelHeaderColumn += "'" + dt.Columns[i].ColumnName + "'" + ",";
                                else
                                ExcelHeaderColumn += "'" + dt.Columns[i].ColumnName + "'";
                            }

                            SQLQueryToGetMatchingColumn = "select STUFF((Select  ',['+Column_Name+']' from Information_schema.Columns where Table_Name='" +
                                TableName + "' and Table_SChema='" + SchemaName + "'" +
                                "and Column_Name in (" + @ExcelHeaderColumn + ") for xml path('')),1,1,'') AS ColumnList";

                            // MessageBox.Show(SQLQueryToGetMatchingColumn);
                            // MessageBox.Show(ExcelHeaderColumn);


                            //Get Matching Column List from SQL Server
                            string SQLColumnList = "";
                            SqlCommand cmd = myADONETConnection.CreateCommand();
                            cmd.CommandText = SQLQueryToGetMatchingColumn;
                            SQLColumnList = (string)cmd.ExecuteScalar();

                            // MessageBox.Show(" Matching Columns: " + SQLColumnList);


                            //Use Actual Matching Columns to get data from Excel Sheet
                            OleDbConnection cnn1 = new OleDbConnection(ConStr);
                            cnn1.Open();
                            OleDbCommand oconn1 = new OleDbCommand("select " + SQLColumnList + ",'"+filename+"' AS FileName"+ ",'"+sheetname+"' AS SheetName from [" + sheetname + "]", cnn1);
                            OleDbDataAdapter adp1 = new OleDbDataAdapter(oconn1);
                            DataTable dt1 = new DataTable();
                            adp1.Fill(dt1);
                            cnn1.Close();


                            //Load Data from DataTable to SQL Server Table.
                            using (SqlBulkCopy BC = new SqlBulkCopy(myADONETConnection))
                            {
                                BC.DestinationTableName = SchemaName + "." + TableName;
                                foreach (var column in dt1.Columns)
                               BC.ColumnMappings.Add(column.ToString(), column.ToString());
                                BC.WriteToServer(dt1);
                            }

                        }
                    }
                   
                }


Step 5: Run SSIS Package to Load Excel Data with Excel File and Excel Sheet Information
Save the script and Close the Script Task Editor. Run your SSIS Package. It should load data from Excel Sheets to your Table and also insert Excel file name and sheet name from where the data is loaded. 

I executed the SSIS Package and here is my output.
How to load Excel File Name and Sheet Name with Data to SQL Server Table by using SSIS Package- Script Task C# Scripting Language


As you can see that data is loaded from two Excel files. First Excel file had two sheets and data is loaded from both. The second Excel file had only single sheet and you can see in above picture data is loaded with file name and sheet name.





Check out our other posts/videos for Dynamic Excel Source and Destination
  1. How to Load Data from Excel Files when Number of Columns can decrease or order is changed in Excel Sheet
  2. How to Load Only Matching Column Data to SQL Server Table from Multiple Excel Files (Single Sheet per file) Dynamically in SSIS Package
  3. How to Load Excel File Names with Sheet Names ,Row Count,Last Modified Date, File Size in SQL Server Table
  4. How to Load Multiple Excel Files with Multiple Sheets to Single SQL Server Table by using SSIS Package
  5. How to Load Matching Sheets from Excel to Table and Log Not Matching Sheets Information in SQL Server Table
  6. How to create Table for each sheet in Excel Files and load data to it dynamically in SSIS Package
  7. How to Create Table per Excel File and Load all Sheets Data Dynamically in SSIS Package by using Script Task 
  8. How to create CSV file per Excel File and Load All Sheets from Excel File to it in SSIS Package
  9. How to Create CSV File for Each Excel Sheet from Excel Files in SSIS Package
  10. How to Load Excel File Name and Sheet Name with Data to SQL Server in SSIS Package
  11. How to Import data from Multiple Excel Sheets with a pattern of sheet names from Multiple Excel File in SSIS Package
  12. How to import Data from Excel Files for specific Sheet Name to SQL Server Table in SSIS Package
  13. Load Data To Tables according to Excel Sheet Names from Excel Files dynamically in SSIS Package
  14. How to Load Excel Files with Single/ Multiple Sheets to SQL Server Tables according to Excel File Name Dynamically
  15. How to Read Excel Sheet Data after Skipping Rows in SSIS Package by using Script Task 
  16. How to read data from Excel Sheet and Load to Multiple Tables by using Script Task in SSIS Package
  17. How to create Excel File Dynamically from SQL server Table/View by using Script Task in SSIS Package
  18. How to create Excel File Dynamically for Stored Procedure Results in SSIS Package by using Script Task
  19. How to Export SQL Server Tables from Database to Excel File Dynamically in SSIS Package by using Script Task
  20. How to Convert CSV/Text Files to Excel Files in SSIS Package by using Script Task
  21. How to Load All CSV Files to Excel Sheets ( Sheet Per CSV) in single Excel File in SSIS Package
  22. How to Load All CSV Files to Single Excel Sheet with File Names in an Excel File Dynamically in SSIS Package
  23. How to Create Sample Excel file with Sheet from each table with Top 1000 Rows per sheet in SSIS Package
  24. How to Export Data to Multiple Excel Sheets from Single SQL Server Table in SSIS Package

10 comments:

  1. Concentrate on existing, not accomplishing more – The essential focal point of the promoting groups is to fortify their situation in their current business, not on investigating new roads of development.Data Analytics Course

    ReplyDelete
  2. Pretty good post. I just stumbled upon your blog and wanted to say that I have really enjoyed reading your blog posts. Any way I'll be subscribing to your feed and I hope you post again soon. Big thanks for the useful info. word mixer

    ReplyDelete
  3. You make so many great points here that I read your article a couple of times. Your views are in accordance with my own for the most part. This is great content for your readers. shops names

    ReplyDelete
  4. You know your projects stand out of the herd. There is something special about them. It seems to me all of them are really brilliant! shops names

    ReplyDelete
  5. I really loved reading your blog. It was very well authored and easy to understand. Unlike other blogs I have read which are really not that good.Thanks alot! digital marketing agency

    ReplyDelete
  6. Superbly written article, if only all bloggers offered the same content as you, the internet would be a far better place.. unique business names

    ReplyDelete
  7. Your work is truly appreciated round the clock and the globe. It is incredibly a comprehensive and helpful blog. techwear-x.com

    ReplyDelete
  8. I haven’t any word to appreciate this post.....Really i am impressed from this post....the person who create this post it was a great human..thanks for shared this with us. creative business name

    ReplyDelete
  9. Wow, cool post. I’d like to write like this too – taking time and real hard work to make a great article… but I put things off too much and never seem to get started. Thanks though. company name ideas

    ReplyDelete