|
/*The need to produce Excel reports from SQL Server is very common. Here, Robyn Page and Phil Factor present practical techniques for creating and manipulating Excel spreadsheets from SQL Server, using linked servers and T-SQL. The pièce de résistance is a stored procedure that uses OLE Automation to allow you full control over the formatting of your Excel report, and the ability to include sums, ranges, pivot tables and so on. */
/*
The C.R.U.D. of Excel
=====================
Phil and I have teamed up on this workbench, which demonstrates how to create, read, update and delete information in Excel using T-SQL, from SQL Server. As always, the workbench is structured so that it can be pasted into Query Analyser and SSMS, and the individual examples executed - you can download the .sql from the "Code Download" link above, load it up and start experimenting!
Contents
========
Creating Excel spreadsheets via ADODB
Manipulating Excel data via a linked server
Synchronising the Spreadsheet with SQL Server Tables
Manipulating Excel data using OPENDATASOURCE and OPENROWSET functions
Creating Excel spreadsheets using sp_MakeWebTask
OLE Automation
We start by showing you how to create an Excel Spreadsheet from SQL Server in TSQL(Transact SQL), create a worksheet, attach to it as a linked server, write to it, read from it, update it as if it was an ordinary SQL Server Database table, and then synchronise the data in the worksheet with SQL Server. We also illustrate the use of OPENQUERY, OPENDATASOURCE and OPENROWSET.
To create the Excel spreadsheet, we show how to attach to an ADODB source from SQL Server and execute SQL against that source. We then show you an alternative 'quick cheat' way (using sp_makewebtask) to create and populate an excel spreadsheet from Transact SQL.
If you need more control over the Excel Spreadsheet that you are creating, we then show you how to do it via OLE automation. This will enable you to do anything you can do via keystrokes, and allow you to generate full Excel reports with pivot tables and Graphs.
Using this technique, you should be able to populate the data, or place data in particular calls or ranges. You can even do 'macro substitutions'
A word of caution before you start. If you have your security wide open, it is not just you who would be able to write out data as a spreadsheet. An intruder would be able to do it with that list of passwords or credit-card numbers. In a production system, this sort of operation needs to be properly ring-fenced. We tend to create a job queue and have a special user, with the appropriate permissions, on the Task Scheduler, to do anything that involves OLE automation or xp_CMDShell. Security precautions can get quite complex, but they are outside the scope of the article.
Some of what we illustrate can be done using DTS or SSIS. Unfortunately, these are outside the scope of this article. In fact, transferring data between Excel and SQL Server can be done in a surprising variety of ways and it would be fun one day to
try to list them all
First we need some simple test data
*/
CREATE TABLE ##CambridgePubs
(Pubname VARCHAR(40),
Address VARCHAR(80),
Postcode VARCHAR(8))
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Bees In The Wall','36 North Road,
Whittlesford, Cambridge','CB2 4NZ'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Blackamoors Head','205 Victoria Road,
Cambridge','CB4 3LF'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Blue Lion','2 Horningsea Road,
Fen Ditton, Cambridge','CB5 8SZ'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Cambridge Blue','85-87 Gwydir Street,
Cambridge','CB1 2LG'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Champion Of The Thames','68 King Street,
Cambridge','CB1 1LN'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Cross Keys','77 Ermine Street,
Caxton, Cambridge','CB3 8PQ'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Crown Inn','11 High Street,
Linton, Cambridge','CB1 6HS'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Devonshire Arms','1 Devonshire Road,
Cambridge','CB1 2BH'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Duke Of Argyle','90 Argyle Street,
Cambridge','CB1 3LS'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Duke Of Wellington','49 Alms Hill,
Bourn, Cambridge','CB3 7SH'
INSERT INTO ##CambridgePubs (PubName, Address, Postcode)
SELECT 'Eagle Public House','Benet Street,
Cambridge','CB2 3QN'
/*And so on. (The full import file is in the ZIP, as is the Excel
file!)
Create the table and then execute the contents of CambridgePubs.SQL
Creating Excel spreadsheets via ADODB -----------------------------------------
First, we need to create the spreadsheet with the correct headings (PubName, Address, PostCode)
There are two possible ways one might do this. The most obvious way is using the CREATE statement to create the worksheet and define the columns, but there seems to be no way of doing this by linking the excel FILE, unless the Excel file already exists. We need a utility stored procedure to get at ADODB in order to create databases and execute DDL and SQL against it. */
CREATE PROCEDURE spExecute_ADODB_SQL
@DDL VARCHAR(2000),
@DataSource VARCHAR(100),
@Worksheet VARCHAR(100)=NULL,
@ConnectionString VARCHAR(255)
= 'Provider=Microsoft.Jet.OLEDB.4.0;
Data Source=%DataSource;
Extended Properties=Excel 8.0'
AS
DECLARE
@objExcel INT,
@hr INT,
@command VARCHAR(255),
@strErrorMessage VARCHAR(255),
@objErrorObject INT,
@objConnection INT,
@bucket INT
SELECT @ConnectionString
=REPLACE (@ConnectionString, '%DataSource', @DataSource)
IF @Worksheet IS NOT NULL
SELECT @DDL=REPLACE(@DDL,'%worksheet',@Worksheet)
SELECT @strErrorMessage='Making ADODB connection ',
@objErrorObject=NULL
EXEC @hr=sp_OACreate 'ADODB.Connection', @objconnection OUT
IF @hr=0
SELECT @strErrorMessage='Assigning ConnectionString property "'
+ @ConnectionString + '"',
@objErrorObject=@objconnection
IF @hr=0 EXEC @hr=sp_OASetProperty @objconnection,
'ConnectionString', @ConnectionString
IF @hr=0 SELECT @strErrorMessage
='Opening Connection to XLS, for file Create or Append'
IF @hr=0 EXEC @hr=sp_OAMethod @objconnection, 'Open'
IF @hr=0 SELECT @strErrorMessage
='Executing DDL "'+@DDL+'"'
IF @hr=0 EXEC @hr=sp_OAMethod @objconnection, 'Execute',
@Bucket out , @DDL
IF @hr<>0
BEGIN
DECLARE
@Source VARCHAR(255),
@Description VARCHAR(255),
@Helpfile VARCHAR(255),
@HelpID INT
EXECUTE sp_OAGetErrorInfo @objErrorObject, @source output,
@Description output,@Helpfile output,@HelpID output
SELECT @strErrorMessage='Error whilst '
+COALESCE(@strErrorMessage,'doing something')+', '
+COALESCE(@Description,'')
RAISERROR (@strErrorMessage,16,1)
END
EXEC @hr=sp_OADestroy @objconnection
GO
--------------------------------------
/* Now we have it, it is easy */
spExecute_ADODB_SQL @DDL='Create table CambridgePubs
(Pubname Text, Address Text, Postcode Text)',
@DataSource ='C:\CambridgePubs.xls'
--the excel file will have been created on the Database server of the
-- database you currently have a connection to
--We could now insert data into the spreadsheet, if we wanted
spExecute_ADODB_SQL @DDL='insert into CambridgePubs
(Pubname,Address,Postcode)
values (''The Bird in Hand'',
''23, Marshall Road, Cambridge CB4 2DQ'',
''CB4 2DQ'')',
@DataSource ='C:\CambridgePubs.xls'
--you could drop it again!
spExecute_ADODB_SQL @DDL='drop table CambridgePubs',
@DataSource ='c:\CambridgePubs.xls'
/* Manipulating Excel data via a linked server ----------------------------------------------
We can now link to the created excel file as follows */
EXEC sp_addlinkedserver 'CambridgePubDatabase',
@srvproduct = '',
@provider = 'Microsoft.Jet.OLEDB.4.0',
@datasrc = 'C:\CambridgePubs.xls',
@provstr = 'Excel 8.0;'
GO
EXEC sp_addlinkedsrvlogin 'CambridgePubDatabase', 'false'
GO
by Robyn Page and Phil Factor
|