Archive
Query Excel file source through Linked Server
In previous post we saw how to setup a Linked Server for MySQL Database. Now lets go with other data sources. Excel files are the most important source of data and report management in a particular department.
When you need to do some query on Excel data, one way is to use Import/Export wizard, push the excel contents to SQL Server and then query on SQL Server DB. Another and easy way is to create a Linked Server to Excel file and query directly the Excel file itself.
You just need to create the Excel file and execute the following SQL Statements below:
–> For Excel 2003 format:
USE MSDB GO EXEC sp_addLinkedServer @server= 'XLS_NewSheet', @srvproduct = 'Jet 4.0', @provider = 'Microsoft.Jet.OLEDB.4.0', @datasrc = 'C:\Manoj_Advantage\NewSheet.xls', @provstr = 'Excel 5.0; HDR=Yes'
– Now, query your excel file in two ways:
SELECT * FROM OPENQUERY (XLS_NewSheet, 'Select * from [Sheet1$]') SELECT * FROM XLS_NewSheet...[Sheet1$]
–> For Excel 2007 format:
USE MSDB GO EXEC sp_addLinkedServer @server= 'XLSX_NewSheet', @srvproduct = 'ACE 12.0', @provider = 'Microsoft.ACE.OLEDB.12.0', @datasrc = 'C:\Manoj_Advantage\NewSheet.xlsx', @provstr = 'Excel 12.0; HDR=Yes'
– Now, query your excel file in two ways:
SELECT * FROM OPENQUERY (XLSX_NewSheet, 'Select * from [Sheet1$]') SELECT * FROM XLSX_NewSheet...[Sheet1$]
Note: If your excel file don’t have headers, then set HDR=No
You may need to execute the following SQL Statements to configure the Linked Server initially:
USE MSDB GO sp_configure 'show advanced options', 1 GO RECONFIGURE WITH OverRide GO sp_configure 'Ad Hoc Distributed Queries', 1 GO RECONFIGURE WITH OverRide GO
>> Check & Subscribe my [YouTube videos] on SQL Server.