To, Import/Export data To/From Excel (.xls) need Microsoft.Jet.OLEDB.4.0 and for Excel 2007 (.xlsx) need2007 Office System Driver: Data Connectivity Components. You can download from here.
Export Data to Excel file
Create an Excel file named testing having the headers same as that of SQLServerTable columns
Here is Query:
Excel 2003 (.Xls) file:
Create an Excel file named testing having the headers same as that of SQLServerTable columns
Here is Query:
Excel 2003 (.Xls) file:
1
| insert into OPENROWSET('Microsoft.Jet.OLEDB.4.0', 'Excel 8.0;Database=D:testing.xls;', 'SELECT * FROM [Sheet1$]') select * from SQLServerTable |
Excel 2007 (.Xlsx) file:
1
| insert into OPENROWSET('Microsoft.ACE.OLEDB.12.0', 'Excel 12.0;Database=D:testing.xlsx;', 'SELECT * FROM [Sheet1$]') select * from SQLServerTable |
Import data from Excel to new SQL Server Table
Excel 2003 (.Xls) file:
Excel 2003 (.Xls) file:
1
| select * into SQLServerTable FROM OPENROWSET('Microsoft.Jet.OLEDB.4.0', 'Excel 8.0;Database=D:testing.xls;HDR=YES', 'SELECT * FROM [Sheet1$]') |
Excel 2007 (.Xlsx) file:
1
| Select * into SQLServerTable FROM OPENROWSET('Microsoft.ACE.OLEDB.12.0', 'Excel 12.0;Database=D:testing.xlsx;HDR=YES', 'SELECT * FROM [Sheet1$]') |
Import data from Excel to existing SQL Server table
Excel 2003 (.Xls) file:
Excel 2003 (.Xls) file:
1
| Insert into SQLServerTable Select * FROM OPENROWSET('Microsoft.Jet.OLEDB.4.0', 'Excel 8.0;Database=D:testing.xls;HDR=YES', 'SELECT * FROM [Sheet1$]') |
Excel 2007 (.Xlsx) file:
1
| INSERT INTO SQLServerTable select * FROM OPENROWSET('Microsoft.ACE.OLEDB.12.0', 'Excel 12.0;Database=D:testing.xlsx;HDR=YES', 'SELECT * FROM [Sheet1$]') |
Import data from Excel to new SQL Server table with dynamic table name (ex. SQLTABLE_200110413)
1
2
3
4
5
| DECLARE @table varchar(500)DECLARE @Q varchar(2000 )SET @table='SQLTABLE_' +(CONVERT(VARCHAR(8),GETDATE(),112))SET @Q= 'select * into '+ @table + ' FROM OPENROWSET("Microsoft.ACE.OLEDB.12.0", "Excel 12.0;Database=D:testing.xlsx;HDR=YES", "SELECT * FROM [Sheet1$]")'Exec(@Q) |
May be you find error like below while Import/Export data To/From Excel
Error 1:
Error 1:
1
2
3
4
| Msg 7399, Level 16, State 1, Line 1The OLE DB provider "Microsoft.ACE.OLEDB.12.0" for linked server "(null)" reported an error. Access denied.Msg 7350, Level 16, State 2, Line 1Cannot get the column information from OLE DB provider "Microsoft.ACE.OLEDB.12.0" for linked server "(null)". |
Here is solution might work for you..
1
2
3
4
5
6
| USE [master]GOEXEC master.dbo.sp_MSset_oledb_prop N'Microsoft.ACE.OLEDB.12.0', N'AllowInProcess', 1GOEXEC master.dbo.sp_MSset_oledb_prop N'Microsoft.ACE.OLEDB.12.0', N'DynamicParameters', 1GO |
Error 2:
1
2
| Msg 15281, Level 16, State 1, Line 1SQL Server blocked access to STATEMENT 'OpenRowset/OpenDatasource' of component 'Ad Hoc Distributed Queries' because this component is turned off as part of the security configuration for this server. A system administrator can enable the use of 'Ad Hoc Distributed Queries' by using sp_configure. For more information about enabling 'Ad Hoc Distributed Queries', see "Surface Area Configuration" in SQL Server Books Online. |
here is solution might work for you
1
2
3
4
| EXEC sp_configure 'show advanced options', 1RECONFIGUREEXEC sp_configure 'Ad Hoc Distributed Queries', 1RECONFIGURE |
If above Query showing following error…
1
2
3
| Configuration option 'show advanced options' changed from 0 to 1. Run the RECONFIGURE statement to install.Msg 5808, Level 16, State 1, Line 2Ad hoc update to system catalogs is not supported. |
then user RECONFIGURE WITH OVERRIDE instead of RECONFIGURE..
1
2
3
4
| EXEC sp_configure 'show advanced options', 1RECONFIGURE WITH OVERRIDEEXEC sp_configure 'Ad Hoc Distributed Queries', 1RECONFIGURE WITH OVERRIDE |
No comments:
Post a Comment