Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 389
Default SUMPRODUCT with Hidden Columns

How can I finesse SUMPRODUCT to ignore hidden columns? For example with
column G through M hidden, column D contains resource names, and column F
through AE contain hours:

=SUMPRODUCT(--($d$4:$d125="ResourceName")*($f$4:$ae$125))

  #2   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3,355
Default SUMPRODUCT with Hidden Columns

Your sumproduct won't work because the arrays need to be the same size. You
have one array of $D$4:$D$125 and another with multiple columns. What
exactly do you want to do?

"Steven" wrote:

How can I finesse SUMPRODUCT to ignore hidden columns? For example with
column G through M hidden, column D contains resource names, and column F
through AE contain hours:

=SUMPRODUCT(--($d$4:$d125="ResourceName")*($f$4:$ae$125))

  #3   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 1,231
Default SUMPRODUCT with Hidden Columns

Barb Reinhardt wrote...
Your sumproduct won't work because the arrays need to be the same size. . . .

....

That DOESN'T matter in this case because the OP's formula passes a
SINGLE argument to SUMPRODUCT. The -- at the beginning of that single
argument is unnecessary. Test it if you don't believe me.

"Steven" wrote:
How can I finesse SUMPRODUCT to ignore hidden columns? For example with
column G through M hidden, column D contains resource names, and column F
through AE contain hours:

=SUMPRODUCT(--($d$4:$d125="ResourceName")*($f$4:$ae$125))


Do you mean there to be no $ between d and 125? I'd guess this was a
typo.

You need to use additional cells in columns F to AE that contain
formulas like

F126:
=(CELL("Width",F126)0)*NOW()^0

(The NOW call ensures these formulas recalc upon every minimal recalc
rather than just on full recalcs.) Then change your formula to

=SUMPRODUCT(($D$4:$D$125="ResourceName")*($F$126:$ AE$126)
*($F$4:$AE$125))

  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 3,355
Default SUMPRODUCT with Hidden Columns

I'll check it. Thanks.

"Harlan Grove" wrote:

Barb Reinhardt wrote...
Your sumproduct won't work because the arrays need to be the same size. . . .

....

That DOESN'T matter in this case because the OP's formula passes a
SINGLE argument to SUMPRODUCT. The -- at the beginning of that single
argument is unnecessary. Test it if you don't believe me.

"Steven" wrote:
How can I finesse SUMPRODUCT to ignore hidden columns? For example with
column G through M hidden, column D contains resource names, and column F
through AE contain hours:

=SUMPRODUCT(--($d$4:$d125="ResourceName")*($f$4:$ae$125))


Do you mean there to be no $ between d and 125? I'd guess this was a
typo.

You need to use additional cells in columns F to AE that contain
formulas like

F126:
=(CELL("Width",F126)0)*NOW()^0

(The NOW call ensures these formulas recalc upon every minimal recalc
rather than just on full recalcs.) Then change your formula to

=SUMPRODUCT(($D$4:$D$125="ResourceName")*($F$126:$ AE$126)
*($F$4:$AE$125))


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
SUMPRODUCT with Hidden Columns Steven Excel Worksheet Functions 0 May 7th 07 07:39 PM
Hidden Columns No Longer Hidden after Copying Worksheet? EV Nelson Excel Discussion (Misc queries) 1 December 6th 06 05:10 PM
Need to sum columns, excluding hidden columns. psill Excel Discussion (Misc queries) 7 October 13th 06 07:49 PM
How to keep hidden columns hidden using protection Dave Excel Discussion (Misc queries) 1 March 1st 06 02:20 AM
HIDDEN COLUMNS bpeltzer Excel Discussion (Misc queries) 0 December 27th 05 07:11 PM


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