September 7, 2011 at 7:57 am
I've created a stored procedure that accepts two arguments: the name of an Excel workbook (@workbookBillRun), and the name of the first worksheet found in that workbook (@worksheetBillRun).
Through dynamic SQL, I'm able to construct a statement that pulls out data.
SELECT @sqlBillRun = '
SELECT [ACCTNUM], [INVNUM], [RECURRING], [NON RECURRING], [USAGE],[DISCOUNT],[TAXES]
FROM OPENROWSET (''Microsoft.ACE.OLEDB.12.0'', ''Excel 12.0;;Database=' +@workbookBillRun+ ';HDR=YES'',
''SELECT * from [' +@worksheetBillRun+ '$]'')'
The workbook name will always be known: when the user uploads the file, I change the name to match a certain pattern. Example: 2011-08 AUG.xlsx
However, I won't always know the worksheet name. The workbook *should* contain just one worksheet; and the worksheet *should* be named identically to the workbook (2011-08 AUG), but it may not be named as such. And if I pass an invalid worksheet name, the code above will fail.
I've created error handling to alert the user of an incorrectly named sheet. However, I was curious whether I could extract the name of the first worksheet in the workbook from within T-SQL.
Thanks in advance.
May 7, 2014 at 7:22 am
Did you ever got this to work ?
May 7, 2014 at 10:58 am
Notice that they have not logged in since 2011
May 7, 2014 at 11:56 am
Yes, I have seen this...but sometimes the person who asks the question also finds a solution him- or herself.
HOWEVER, for any future finders of this post, I will answer this one 😉
The key is to dynamically add a (temporary) linked server to the XLSX say e.g. called TempExcelSheet
The you can then query the worksheets and columns using systems stored procedures sp_tables_ex and sp_columns_ex
June 26, 2014 at 5:20 pm
Hi,
What provider did you use when creating your link?
----------------------------------------------------
June 27, 2014 at 1:46 am
This is the code I used...enjoy 🙂
-- Get table (worksheet) or column (field) listings from an excel spreadsheet
DECLARE @linkedServerName sysname = 'TempExcelSpreadsheet'
DECLARE @excelFileUrl nvarchar(1000) = 'D:\\SHARE\\WLAN\\Report.xlsx'
IF OBJECT_ID('tempdb..#MyTempTable') IS NOT NULL
DROP TABLE #MyTempTable;
-- Remove existing linked server (if necessary)
if exists(select null from sys.servers where name = @linkedServerName) begin
exec sp_dropserver @server = @linkedServerName, @droplogins = 'droplogins'
end
-- Add the linked server
-- ACE 12.0 seems to work for both xsl and xslx, though some might prefer the older JET provider
exec sp_addlinkedserver
@server = @linkedServerName,
@srvproduct = 'ACE 12.0',
@provider = 'Microsoft.ACE.OLEDB.12.0',
@datasrc = @excelFileUrl,
@provstr = 'Excel 12.0;HDR=Yes'
-- Grab the current user to use as a remote login
DECLARE @suser_sname NVARCHAR(256) = SUSER_SNAME()
-- Add the current user as a login
EXEC SP_ADDLINKEDSRVLOGIN
@rmtsrvname = @linkedServerName,
@useself = 'false',
@locallogin = @suser_sname,
@rmtuser = null,
@rmtpassword = null
-- Return the table info, each worksheet pbb gets its own unique name
SELECT * INTO #MyTempTable FROM OPENROWSET('SQLNCLI', 'Server=(local);Trusted_Connection=yes;',
'EXEC sp_tables_ex TempExcelSpreadsheet');
SELECT TABLE_NAME
FROM #MyTempTable
--exec sp_executesql 'SELECT * INTO #MyTempTable FROM OPENROWSET(''SQLNCLI'', ''Server=(local);Trusted_Connection=yes;'',''EXEC sp_tables_ex TempExcelSpreadsheet'')'
--EXEC sp_tables_ex @linkedServerName
--EXEC sp_columns_ex @linkedServerName
-- Remove temp linked server
if exists(select null from sys.servers where name = @linkedServerName) begin
exec sp_dropserver @server = @linkedServerName, @droplogins = 'droplogins'
end
June 27, 2014 at 10:21 am
Very awesome. I'll try it out, Thanks!
----------------------------------------------------
December 23, 2017 at 8:29 am
Hansiehans - Friday, June 27, 2014 1:46 AMThis is the code I used...enjoy 🙂
-- Get table (worksheet) or column (field) listings from an excel spreadsheetDECLARE @linkedServerName sysname = 'TempExcelSpreadsheet'
DECLARE @excelFileUrl nvarchar(1000) = 'D:\\SHARE\\WLAN\\Report.xlsx'IF OBJECT_ID('tempdb..#MyTempTable') IS NOT NULL
DROP TABLE #MyTempTable;-- Remove existing linked server (if necessary)
if exists(select null from sys.servers where name = @linkedServerName) begin
exec sp_dropserver @server = @linkedServerName, @droplogins = 'droplogins'
end-- Add the linked server
-- ACE 12.0 seems to work for both xsl and xslx, though some might prefer the older JET provider
exec sp_addlinkedserver
@server = @linkedServerName,
@srvproduct = 'ACE 12.0',
@provider = 'Microsoft.ACE.OLEDB.12.0',
@datasrc = @excelFileUrl,
@provstr = 'Excel 12.0;HDR=Yes'-- Grab the current user to use as a remote login
DECLARE @suser_sname NVARCHAR(256) = SUSER_SNAME()-- Add the current user as a login
EXEC SP_ADDLINKEDSRVLOGIN
@rmtsrvname = @linkedServerName,
@useself = 'false',
@locallogin = @suser_sname,
@rmtuser = null,
@rmtpassword = null-- Return the table info, each worksheet pbb gets its own unique name
SELECT * INTO #MyTempTable FROM OPENROWSET('SQLNCLI', 'Server=(local);Trusted_Connection=yes;',
'EXEC sp_tables_ex TempExcelSpreadsheet');SELECT TABLE_NAME
FROM #MyTempTable--exec sp_executesql 'SELECT * INTO #MyTempTable FROM OPENROWSET(''SQLNCLI'', ''Server=(local);Trusted_Connection=yes;'',''EXEC sp_tables_ex TempExcelSpreadsheet'')'
--EXEC sp_tables_ex @linkedServerName
--EXEC sp_columns_ex @linkedServerName-- Remove temp linked server
if exists(select null from sys.servers where name = @linkedServerName) begin
exec sp_dropserver @server = @linkedServerName, @droplogins = 'droplogins'
end
I've had this pinned as a link since you posted it and have been seriously remiss in saying "Thank You". Great job (and hat's off to you for the embedded comments that make the code crystal clear) and thanks for sharing even years after the original questions was posted. It's proof positive that all the reminders about how old a post is really don't matter and is definitely worth asking a follow up question or posting an answer even on old posts. Well done and, even though you've not logged on for the previous two months, I hope you're still listening because I think this post has helped a whole lot of people that never took the time to say thanks for solving a fairly common and particularly itchy problem when you're the one that needs a solution.
Shifting gears a bit, this would would make great "SQL Spackle" article. You should write one and submit it. If you want, I'd even be willing to proof it and do a technical review for you.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 23, 2017 at 8:35 am
Jeff, are you working up a huge back-log?
😎
Can we take the Excel thing offline, would like to share some work with you knowing you can write it up much better than I ever could?
December 23, 2017 at 9:07 am
Eirikur Eiriksson - Saturday, December 23, 2017 8:35 AMJeff, are you working up a huge back-log?
😎
Can we take the Excel thing offline, would like to share some work with you knowing you can write it up much better than I ever could?
You should see my presentation on "Automating Excel Hell", which explains how to write "self healing" imports for typical "horizontal" spreadsheets that change every bloody week. Sounds like we may be cut from the same cloth on this subject and I'd love to talk about it. Do you have my private email address?
--Jeff Moden
Change is inevitable... Change for the better is not.
December 26, 2017 at 9:44 pm
Eirikur Eiriksson - Saturday, December 23, 2017 8:35 AMJeff, are you working up a huge back-log?
😎
Can we take the Excel thing offline, would like to share some work with you knowing you can write it up much better than I ever could?
Did you see my note above? Yes, I'm interested!
--Jeff Moden
Change is inevitable... Change for the better is not.
January 3, 2018 at 3:25 am
Hansiehans - Friday, June 27, 2014 1:46 AM
I've had this pinned as a link since you posted it and have been seriously remiss in saying "Thank You". Great job (and hat's off to you for the embedded comments that make the code crystal clear) and thanks for sharing even years after the original questions was posted. It's proof positive that all the reminders about how old a post is really don't matter and is definitely worth asking a follow up question or posting an answer even on old posts. Well done and, even though you've not logged on for the previous two months, I hope you're still listening because I think this post has helped a whole lot of people that never took the time to say thanks for solving a fairly common and particularly itchy problem when you're the one that needs a solution.
Shifting gears a bit, this would would make great "SQL Spackle" article. You should write one and submit it. If you want, I'd even be willing to proof it and do a technical review for you.
Hi Jeff,
Yes I am still here 🙂
Thanks for the compliment.
Reading back, the code is not quite as I would write it right now (like all SQL words in capitals) etc
And I do regularly read the articles on the website, I just do not logon 😉
January 3, 2018 at 5:05 pm
Jeff Moden - Saturday, December 23, 2017 8:29 AMHansiehans - Friday, June 27, 2014 1:46 AMI've had this pinned as a link since you posted it and have been seriously remiss in saying "Thank You". Great job (and hat's off to you for the embedded comments that make the code crystal clear) and thanks for sharing even years after the original questions was posted. It's proof positive that all the reminders about how old a post is really don't matter and is definitely worth asking a follow up question or posting an answer even on old posts. Well done and, even though you've not logged on for the previous two months, I hope you're still listening because I think this post has helped a whole lot of people that never took the time to say thanks for solving a fairly common and particularly itchy problem when you're the one that needs a solution.
Shifting gears a bit, this would would make great "SQL Spackle" article. You should write one and submit it. If you want, I'd even be willing to proof it and do a technical review for you.
Hi Jeff,
Yes I am still here 🙂
Thanks for the compliment.
Reading back, the code is not quite as I would write it right now (like all SQL words in capitals) etc
And I do regularly read the articles on the website, I just do not logon 😉
Good to know you're still out there. Seriously, you should write an article on this and submit it to this site. It would do a lot of people good, including yourself.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 4, 2018 at 3:47 am
Jeff,
Are you planning to speak at any European conference this year (SQL Bits?) I would love the chance to shake your hand and thank you personally for your contributions to the SQL legion of Doom.
The same goes for Erik, Grant F, Lynn P and all the other regular posters. I had the good fortune to meet Gail Shaw a few years ago at SQL Bits and I also have a selfie with THE MAN (Steve Jones) including his very loud Hawaiian shirt 🙂
January 4, 2018 at 6:09 am
aaron.reese - Thursday, January 4, 2018 3:47 AMJeff,Are you planning to speak at any European conference this year (SQL Bits?) I would love the chance to shake your hand and thank you personally for your contributions to the SQL legion of Doom.
The same goes for Erik, Grant F, Lynn P and all the other regular posters. I had the good fortune to meet Gail Shaw a few years ago at SQL Bits and I also have a selfie with THE MAN (Steve Jones) including his very loud Hawaiian shirt 🙂
Thanks for that, Aaron. I'd take great relish in being able to meet in person many of those that I've worked with through this and other sites. Unfortunately, I suffer from the not-so-rare Italian disease of "mefundsarelow" and I'm "just" a regular working stiff with no sponsors. It's not likely that I'll ever be able to make it to the other side of the pond. Shoot... most of the time (I've only been to 2), I can't even make it to the PASS Summit or any of the other conferences in the U.S.A. I even have an SQL Saturday in Colorado Springs on my bucket list but I can't justify the personal expense of going.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply