ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   condense formula that sums 4 adjacent columns (https://www.excelbanter.com/excel-discussion-misc-queries/178047-condense-formula-sums-4-adjacent-columns.html)

stevec

condense formula that sums 4 adjacent columns
 
Any suggestions on how to make this shorter?

=INDEX(OFA!$DM$4:$DM$6000,MATCH(A2,OFA!$D$4:$D$600 0,0),1)+INDEX(OFA!$DN$4:$DN$6000,MATCH(A2,OFA!$D$4 :$D$6000,0),1)+INDEX(OFA!$DO$4:$DO$6000,MATCH(A2,O FA!$D$4:$D$6000,0),1)+INDEX(OFA!$DP$4:$DP$6000,MAT CH(A2,OFA!$D$4:$D$6000,0),1)

many thanks!

SteveC



JE McGimpsey

condense formula that sums 4 adjacent columns
 
One way:

=SUM(OFFSET(OFA!$DM3,MATCH(A2,OFA!$D$4:$D$6000,FAL SE),,,4))


In article ,
SteveC wrote:

Any suggestions on how to make this shorter?

=INDEX(OFA!$DM$4:$DM$6000,MATCH(A2,OFA!$D$4:$D$600 0,0),1)+INDEX(OFA!$DN$4:$DN$
6000,MATCH(A2,OFA!$D$4:$D$6000,0),1)+INDEX(OFA!$DO $4:$DO$6000,MATCH(A2,OFA!$D$
4:$D$6000,0),1)+INDEX(OFA!$DP$4:$DP$6000,MATCH(A2, OFA!$D$4:$D$6000,0),1)

many thanks!

SteveC


stevec

condense formula that sums 4 adjacent columns
 
JE, this formula works great, thanks.

I don't understand though why the you are replacing the DM4 and DM3 though.
Would have thought DM4 would have stayed DM4. If you have time, can you
explain how that works? I need to understand OFFSET better... thanks very
much for your help. SteveC

"JE McGimpsey" wrote:

One way:

=SUM(OFFSET(OFA!$DM3,MATCH(A2,OFA!$D$4:$D$6000,FAL SE),,,4))


In article ,
SteveC wrote:

Any suggestions on how to make this shorter?

=INDEX(OFA!$DM$4:$DM$6000,MATCH(A2,OFA!$D$4:$D$600 0,0),1)+INDEX(OFA!$DN$4:$DN$
6000,MATCH(A2,OFA!$D$4:$D$6000,0),1)+INDEX(OFA!$DO $4:$DO$6000,MATCH(A2,OFA!$D$
4:$D$6000,0),1)+INDEX(OFA!$DP$4:$DP$6000,MATCH(A2, OFA!$D$4:$D$6000,0),1)

many thanks!

SteveC



JE McGimpsey

condense formula that sums 4 adjacent columns
 
MATCH returns 1 if it finds a match in the first cell of the array, so
if we used

...OFFSET(OFA!$DM4, 1...

it would start with DM5.

An alternative would be:

=SUM(OFFSET(OFA!$DM4,MATCH(A2,OFA!$D$4:$D$6000,FAL SE) - 1,,,4))

In article ,
SteveC wrote:

I don't understand though why the you are replacing the DM4 and DM3 though.
Would have thought DM4 would have stayed DM4. If you have time, can you
explain how that works? I need to understand OFFSET better... thanks very
much for your help. SteveC

"JE McGimpsey" wrote:

One way:

=SUM(OFFSET(OFA!$DM3,MATCH(A2,OFA!$D$4:$D$6000,FAL SE),,,4))


stevec

condense formula that sums 4 adjacent columns
 
thanks again.

T. Valko

condense formula that sums 4 adjacent columns
 
Another one:

=SUM(INDEX(OFA!DM4:DP6000,MATCH(A2,OFA!D4:D6000,0) ,))


--
Biff
Microsoft Excel MVP


"SteveC" wrote in message
...
Any suggestions on how to make this shorter?

=INDEX(OFA!$DM$4:$DM$6000,MATCH(A2,OFA!$D$4:$D$600 0,0),1)+INDEX(OFA!$DN$4:$DN$6000,MATCH(A2,OFA!$D$4 :$D$6000,0),1)+INDEX(OFA!$DO$4:$DO$6000,MATCH(A2,O FA!$D$4:$D$6000,0),1)+INDEX(OFA!$DP$4:$DP$6000,MAT CH(A2,OFA!$D$4:$D$6000,0),1)

many thanks!

SteveC






All times are GMT +1. The time now is 02:39 AM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com