#1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 10
Default Return 3D array?

Greetings,

My goal is to return a list of worksheet names on a sheet called "Summary".
I have 30+ sheets. The first is Named "First" and the last is Named "Last".
In A1 of each sheet






  #2   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 10
Default Return 3D array?

My appologies.
Sent to soon.
I'll finish here.


Greetings,

My goal is to return a list of worksheet names on a sheet called "Summary".
I have 30+ sheets. The first is Named "First" and the last is Named "Last".
In A1 of each sheet is the formula to return the sheet name _
=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
I've created a 3D reference called "SheetNames" =First:Last!$A$1
The formula =INDEX(SheetNames,1) returns #Value!
How can I return a 3D array as I would a 2D array?
Thanks.


  #3   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 1,766
Default Return 3D array?

Hi,

You cannot specify a 3D reference in the Name box. I suggest you use the
morefunc Excel addin and then use the sheetname formula.

--
Regards,

Ashish Mathur
Microsoft Excel MVP
www.ashishmathur.com

"Dave P" wrote in message
...
Greetings,

My goal is to return a list of worksheet names on a sheet called
"Summary".
I have 30+ sheets. The first is Named "First" and the last is Named
"Last".
In A1 of each sheet






  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 272
Default Return 3D array?

You can't use INDEX with multiple sheet references - 3D formula functionality
is very limited in Excel.

If you just want a list of worksheets you can just enter directly into the
immediate window [Alt+F11 Ctrl+G]:

for each s in activeworkbook.Sheets: _
activecell.Offset(1,0).Select: _
activecell.Value = s.name: _
next s

(selecting the last line and pressing enter to run it).

If you need a dynamic array of worksheet names you could define the name
"Sheets" to refer to:

=TRANSPOSE(GET.WORKBOOK(1))&T(NOW())

and then select the cells to fill and CTRL+SHIFT+ENTER:

=MID(Sheets,FIND("]",Sheets)+1,255)


"Dave P" wrote:

My appologies.
Sent to soon.
I'll finish here.


Greetings,

My goal is to return a list of worksheet names on a sheet called "Summary".
I have 30+ sheets. The first is Named "First" and the last is Named "Last".
In A1 of each sheet is the formula to return the sheet name _
=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
I've created a 3D reference called "SheetNames" =First:Last!$A$1
The formula =INDEX(SheetNames,1) returns #Value!
How can I return a 3D array as I would a 2D array?
Thanks.



  #5   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3
Default Return 3D array?

Lori,

Thank you very much for the reply. I think this will work well.

Dave

"Lori" wrote in message
...
You can't use INDEX with multiple sheet references - 3D formula
functionality
is very limited in Excel.

If you just want a list of worksheets you can just enter directly into the
immediate window [Alt+F11 Ctrl+G]:

for each s in activeworkbook.Sheets: _
activecell.Offset(1,0).Select: _
activecell.Value = s.name: _
next s

(selecting the last line and pressing enter to run it).

If you need a dynamic array of worksheet names you could define the name
"Sheets" to refer to:

=TRANSPOSE(GET.WORKBOOK(1))&T(NOW())

and then select the cells to fill and CTRL+SHIFT+ENTER:

=MID(Sheets,FIND("]",Sheets)+1,255)


"Dave P" wrote:

My appologies.
Sent to soon.
I'll finish here.


Greetings,

My goal is to return a list of worksheet names on a sheet called
"Summary".
I have 30+ sheets. The first is Named "First" and the last is Named
"Last".
In A1 of each sheet is the formula to return the sheet name _
=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
I've created a 3D reference called "SheetNames" =First:Last!$A$1
The formula =INDEX(SheetNames,1) returns #Value!
How can I return a 3D array as I would a 2D array?
Thanks.







  #6   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3
Default Return 3D array?

Thank you very much for this information. I will explore the addin.

Dave


"Ashish Mathur" wrote in message
...
Hi,

You cannot specify a 3D reference in the Name box. I suggest you use the
morefunc Excel addin and then use the sheetname formula.

--
Regards,

Ashish Mathur
Microsoft Excel MVP
www.ashishmathur.com

"Dave P" wrote in message
...
Greetings,

My goal is to return a list of worksheet names on a sheet called
"Summary".
I have 30+ sheets. The first is Named "First" and the last is Named
"Last".
In A1 of each sheet








  #7   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3
Default Return 3D array?

Lori!

This defined name and array formula reference to "Sheets" is fantastic!
Exactly what I needed: a way to keep the list automatically updated in the
event that a tab name is changed.
Thanks again!

Dave


"Lori" wrote in message
...
You can't use INDEX with multiple sheet references - 3D formula
functionality
is very limited in Excel.

If you just want a list of worksheets you can just enter directly into the
immediate window [Alt+F11 Ctrl+G]:

for each s in activeworkbook.Sheets: _
activecell.Offset(1,0).Select: _
activecell.Value = s.name: _
next s

(selecting the last line and pressing enter to run it).

If you need a dynamic array of worksheet names you could define the name
"Sheets" to refer to:

=TRANSPOSE(GET.WORKBOOK(1))&T(NOW())

and then select the cells to fill and CTRL+SHIFT+ENTER:

=MID(Sheets,FIND("]",Sheets)+1,255)


"Dave P" wrote:

My appologies.
Sent to soon.
I'll finish here.


Greetings,

My goal is to return a list of worksheet names on a sheet called
"Summary".
I have 30+ sheets. The first is Named "First" and the last is Named
"Last".
In A1 of each sheet is the formula to return the sheet name _
=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
I've created a 3D reference called "SheetNames" =First:Last!$A$1
The formula =INDEX(SheetNames,1) returns #Value!
How can I return a 3D array as I would a 2D array?
Thanks.





Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Return an array of results with a vlookup Singh Excel Discussion (Misc queries) 0 August 7th 08 05:15 PM
Use array to return array of values Brad Excel Worksheet Functions 2 March 30th 06 05:58 PM
Return Array with Array Brad Excel Worksheet Functions 10 November 17th 05 06:45 PM
Return a column # from an array mjack003 Excel Discussion (Misc queries) 9 September 17th 05 07:54 PM
ARRAY FORMULA-RETURN 0 INSTEAD OF #DIV/0 Teri Excel Worksheet Functions 8 January 14th 05 05:45 PM


All times are GMT +1. The time now is 07:21 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"