The following is a modification from the following post:
http://makeashorterlink.com/?U3C856C54
It returns a collection, not an array, due to the option of "repeated" names when there is a print area setup.
I tried using the GET.WORKBOOK(1, ...) XLM macro as well, but a) doesn't work well in VBA, and b) doesn't work with closed workbooks.
<font face=Courier New><SPAN style="color:darkblue">Option</SPAN> <SPAN style="color:darkblue">Explicit</SPAN>
<SPAN style="color:darkblue">Function</SPAN> GetSheetsNames(WBName <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">String</SPAN>) <SPAN style="color:darkblue">As</SPAN> Collection
<SPAN style="color:green">'Needs a reference to:</SPAN>
<SPAN style="color:green">'Microsoft ActiveX Data Object X.X Library</SPAN>
<SPAN style="color:green">'Microsoft ADO Ext. X.X for DLL and Security</SPAN>
<SPAN style="color:darkblue">Dim</SPAN> objConn <SPAN style="color:darkblue">As</SPAN> ADODB.Connection
<SPAN style="color:darkblue">Dim</SPAN> objCat <SPAN style="color:darkblue">As</SPAN> ADOX.Catalog
<SPAN style="color:darkblue">Dim</SPAN> tbl <SPAN style="color:darkblue">As</SPAN> ADOX.Table
<SPAN style="color:darkblue">Dim</SPAN> sConnString <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">String</SPAN>
<SPAN style="color:darkblue">Dim</SPAN> sSheet <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">String</SPAN>
<SPAN style="color:darkblue">Dim</SPAN> Col <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">New</SPAN> Collection
sConnString = "Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=" & WBName & ";" & _
"Extended Properties=Excel 8.0;"
<SPAN style="color:darkblue">Set</SPAN> objConn = <SPAN style="color:darkblue">New</SPAN> ADODB.Connection
objConn.<SPAN style="color:darkblue">Open</SPAN> sConnString
<SPAN style="color:darkblue">Set</SPAN> objCat = <SPAN style="color:darkblue">New</SPAN> ADOX.Catalog
<SPAN style="color:darkblue">Set</SPAN> objCat.ActiveConnection = objConn
<SPAN style="color:darkblue">For</SPAN> <SPAN style="color:darkblue">Each</SPAN> tbl <SPAN style="color:darkblue">In</SPAN> objCat.Tables
sSheet = tbl.Name
sSheet = Application.Substitute(sSheet, "'", "")
sSheet = Left(sSheet, InStr(1, sSheet, "$", 1) - 1)
<SPAN style="color:darkblue">On</SPAN> <SPAN style="color:darkblue">Error</SPAN> <SPAN style="color:darkblue">Resume</SPAN> <SPAN style="color:darkblue">Next</SPAN>
Col.Add sSheet, sSheet
<SPAN style="color:darkblue">On</SPAN> <SPAN style="color:darkblue">Error</SPAN> <SPAN style="color:darkblue">GoTo</SPAN> 0
<SPAN style="color:darkblue">Next</SPAN> tbl
<SPAN style="color:darkblue">Set</SPAN> GetSheetsNames = Col
objConn.<SPAN style="color:darkblue">Close</SPAN>
<SPAN style="color:darkblue">Set</SPAN> objCat = <SPAN style="color:darkblue">Nothing</SPAN>
<SPAN style="color:darkblue">Set</SPAN> objConn = <SPAN style="color:darkblue">Nothing</SPAN>
<SPAN style="color:darkblue">End</SPAN> <SPAN style="color:darkblue">Function</SPAN>
<SPAN style="color:darkblue">Sub</SPAN> Test()
<SPAN style="color:darkblue">Dim</SPAN> Col <SPAN style="color:darkblue">As</SPAN> Collection, Book <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">String</SPAN>, i <SPAN style="color:darkblue">As</SPAN> <SPAN style="color:darkblue">Long</SPAN>
Book = "C:\Your path\Your file.xls"
<SPAN style="color:darkblue">Set</SPAN> Col = GetSheetsNames(Book)
<SPAN style="color:darkblue">For</SPAN> i = 1 <SPAN style="color:darkblue">To</SPAN> Col.Count
MsgBox Col(i)
<SPAN style="color:darkblue">Next</SPAN> i
<SPAN style="color:darkblue">End</SPAN> <SPAN style="color:darkblue">Sub</SPAN></FONT>