Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 258
Default Indirect worksheet lookup in long formula

Good evening --

I have 3 years of reference data stored in worksheets labeled 2008, 2009,
2010 respectively. I would like to allow the user to select a year in cell
F2, and have the formula select the right page for these sumproduct formulas.
That is, everywhere the formula selects page '2008', I'd like it to select
the worksheet based on what's in cell F2. Here's the formula:

=IF(OR(ISBLANK($B12),$B12="TC",$B12=26),SUMPRODUCT (--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=$B12),'2008'!$D$1:$D$20000), VLOOKUP($B12,Modifiers,3,FALSE)*SUMPRODUCT(--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=""),'2008'!$D$1:$D$20000))

Thanks in advance. I've spent the better part of a day trying to get the
single and double parentheses correct...

Peter
  #3   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 27
Default Indirect worksheet lookup in long formula

INDIRECT() is a volatile function, as is SUMPRODUCT() I believe. Once you
get this working, EVERY CELL with this formula in it will recalculate every
time you change anything anywhere in your workbook. So, I hope you aren't
planning on putting a lot of these formulas in your workbook.

=IF(OR(ISBLANK($B12), $B12="TC", $B12=26), SUMPRODUCT(--(INDIRECT("'" & F2 &
"'!$A$1:$A$20000")=$A12), --(INDIRECT("'" & F2 & "'!$B$1:$B$20000")=$B12),
INDIRECT("'" & F2 & "'!$D$1:$D$20000")), VLOOKUP($B12,Modifiers,3,FALSE) *
SUMPRODUCT(--(INDIRECT("'" & F2 & "'!$A$1:$A$20000")=$A12), --(INDIRECT("'" &
F2 & "'!$B$1:$B$20000")=""), INDIRECT("'" & F2 & "'!$D$1:$D$20000")))


--
"Actually, I *am* a rocket scientist." -- JB

Your feedback is appreciated, click YES if this post helped you.


"pdberger" wrote:

Good evening --

I have 3 years of reference data stored in worksheets labeled 2008, 2009,
2010 respectively. I would like to allow the user to select a year in cell
F2, and have the formula select the right page for these sumproduct formulas.
That is, everywhere the formula selects page '2008', I'd like it to select
the worksheet based on what's in cell F2. Here's the formula:

=IF(OR(ISBLANK($B12),$B12="TC",$B12=26),SUMPRODUCT (--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=$B12),'2008'!$D$1:$D$20000), VLOOKUP($B12,Modifiers,3,FALSE)*SUMPRODUCT(--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=""),'2008'!$D$1:$D$20000))

Thanks in advance. I've spent the better part of a day trying to get the
single and double parentheses correct...

Peter

  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 15,768
Default Indirect worksheet lookup in long formula

INDIRECT() is a volatile function, as is SUMPRODUCT() I believe.

SUMPRODUCT is not volatile.

We can eliminate the use of the volatile INDIRECT and at the same time
greatly reduce the length of the formula by using some defined names.

InsertNameDefine
Name: Sh2008
Refers to: ='2008'!$A$1:$D$20000

Name: Sh2009
Refers to: ='2009'!$A$1:$D$20000

Name: Sh2010
Refers to: ='2010'!$A$1:$D$20000

Name: Sheet
Refers to:
=CHOOSE(MATCH(Sheet1!$F$2,{2008,2009,2010},0),Sh20 08,Sh2009,Sh2010)

Name: Calc
Refers to:

=SUMPRODUCT(--(INDEX(Sheet,,1)=Sheet1!$A$12), --(INDEX(Sheet,,2)=Sheet1!$B$12),
INDEX(Sheet,,4))

Then the formula becomes:

=IF(OR($B12={"","TC",26}),Calc,VLOOKUP($B12,Modifi ers,3,0)*Calc)

--
Biff
Microsoft Excel MVP


"JBeaucaire" wrote in message
...
INDIRECT() is a volatile function, as is SUMPRODUCT() I believe. Once you
get this working, EVERY CELL with this formula in it will recalculate
every
time you change anything anywhere in your workbook. So, I hope you aren't
planning on putting a lot of these formulas in your workbook.

=IF(OR(ISBLANK($B12), $B12="TC", $B12=26), SUMPRODUCT(--(INDIRECT("'" & F2
&
"'!$A$1:$A$20000")=$A12), --(INDIRECT("'" & F2 & "'!$B$1:$B$20000")=$B12),
INDIRECT("'" & F2 & "'!$D$1:$D$20000")), VLOOKUP($B12,Modifiers,3,FALSE) *
SUMPRODUCT(--(INDIRECT("'" & F2 &
"'!$A$1:$A$20000")=$A12), --(INDIRECT("'" &
F2 & "'!$B$1:$B$20000")=""), INDIRECT("'" & F2 & "'!$D$1:$D$20000")))


--
"Actually, I *am* a rocket scientist." -- JB

Your feedback is appreciated, click YES if this post helped you.


"pdberger" wrote:

Good evening --

I have 3 years of reference data stored in worksheets labeled 2008, 2009,
2010 respectively. I would like to allow the user to select a year in
cell
F2, and have the formula select the right page for these sumproduct
formulas.
That is, everywhere the formula selects page '2008', I'd like it to
select
the worksheet based on what's in cell F2. Here's the formula:

=IF(OR(ISBLANK($B12),$B12="TC",$B12=26),SUMPRODUCT (--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=$B12),'2008'!$D$1:$D$20000), VLOOKUP($B12,Modifiers,3,FALSE)*SUMPRODUCT(--('2008'!$A$1:$A$20000=$A12),--('2008'!$B$1:$B$20000=""),'2008'!$D$1:$D$20000))

Thanks in advance. I've spent the better part of a day trying to get the
single and double parentheses correct...

Peter



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
lookup and worksheet name and then do formula LRM Excel Worksheet Functions 2 February 26th 09 03:55 PM
Formula to lookup worksheet label Grotejm Excel Worksheet Functions 3 April 3rd 08 05:16 AM
named range in sum formula (indirect, offset, worksheet name) Hans Excel Worksheet Functions 4 February 5th 08 02:14 PM
Indirect formula using Data Validation List of Worksheet Tabs Scott Excel Worksheet Functions 1 December 5th 05 02:59 PM
indirect lookup choice Excel Worksheet Functions 1 February 27th 05 12:12 AM


All times are GMT +1. The time now is 05:31 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"