Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2008 Forums
 SSIS and Import/Export (2008)
 Update a table from MS Excel

Author  Topic 

ugh3012
Yak Posting Veteran

62 Posts

Posted - 2013-11-19 : 08:51:04
I have a MS Excel file. In that file, there is a column with ID that will link to a ID column in a table. I have no clue on how to do that using SSIS. Step by step instructions would be helpful.


MS Excel
ID | Name
1 | Washington
2 | Maine
3 | Jacksonville

Table in SQL Server
ID | Name
1 | Null
2 | NULL
3 | NULL

Desired result in MS SQL Server table
ID | Name
1 | Washington
2 | Maine
3 | Jacksonville



visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-11-19 : 09:20:08
you dont need SSIS for this. A distributed qury using OPENROWSET would be enough. just use like

UPDATE t
SET Name = xl.Name
FROM Table t
INNER JOIN OPENROWSET('Microsoft.Jet.OLEDB.4.0',
'Excel 8.0;Database=Excel File Path;HDR=Yes', 'SELECT * FROM [SheetName$]') xl

or this if excel 2007 or above


UPDATE t
SET Name = xl.Name
FROM Table t
INNER JOIN OPENROWSET('Microsoft.ACE.OLEDB.12.0',
'Excel 12.0;Database=Excel File Path;HDR=Yes',
'SELECT * FROM [SheetName$]') xl


or if you want to use SSIS the flow would be like

data flow task inside which

1. Excel Source - connects to excel
2. Lookup Task based on ID field with SQL ServerTable and retrieve Name from Excel
3. Take MatchOutput and link to OLEDB Command which will do update

But faster approach would be OPENROWSET as its set based. if you want to achieve same in SSIS you would need a staging table which will just stage data from excel inside data flow task and then do update set based in execute sql task

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -