Array formulae question

Peter Adey

New Member
Joined
May 7, 2002
Messages
6
Is it possible to use an array where the variable is a cell reference? This is what I have so far, which is using nested IF statements instead...

=IF(A2=1,D2,IF(A2=3,SUM(D2:F2),IF(A2=6,SUM(D2:I2),IF(A2=9,SUM(D2:L2),IF(A2=12,SUM(D2:O2),IF(A2=15,SUM(D2:R2),"X"))))))

Ideally I would like to refer to the number in A2 and sum that many cells, I have 60 columns of data!

Any ideas???
This message was edited by Peter Adey on 2002-05-08 05:20
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
On 2002-05-08 05:19, Peter Adey wrote:
Is it possible to use an array where the variable is a cell reference? This is what I have so far, which is using nested IF statements instead...

=IF(A2=1,D2,IF(A2=3,SUM(D2:F2),IF(A2=6,SUM(D2:I2),IF(A2=9,SUM(D2:L2),IF(A2=12,SUM(D2:O2),IF(A2=15,SUM(D2:R2),"X"))))))

Ideally I would like to refer to the number in A2 and sum that many cells, I have 60 columns of data!

Any ideas???
This message was edited by Peter Adey on 2002-05-08 05:20
I find the Indirect function useful in cases like this. Try:

=SUM(INDIRECT("D2:D"&(A2+1)))

Regards,

Pete.
 
Upvote 0
On 2002-05-08 05:19, Peter Adey wrote:
Is it possible to use an array where the variable is a cell reference? This is what I have so far, which is using nested IF statements instead...

=IF(A2=1,D2,IF(A2=3,SUM(D2:F2),IF(A2=6,SUM(D2:I2),IF(A2=9,SUM(D2:L2),IF(A2=12,SUM(D2:O2),IF(A2=15,SUM(D2:R2),"X"))))))

Ideally I would like to refer to the number in A2 and sum that many cells, I have 60 columns of data!

Any ideas???
This message was edited by Peter Adey on 2002-05-08 05:20

No need fo an array formula.

=SUM(OFFSET(D2,0,0,1,A2))

will suffice.

Or, with control on A2,

=IF(AND(A2>=1,A2<=15),SUM(OFFSET(D2,0,0,1,A2)),"X")

Aladin
 
Upvote 0
Thanks for the quick reply Rocky

The problem is I don't want sum up the values = A2 . I want to total the number of cells = A2. So,

IF a2= 9 then sum 9 cells etc, etc

any ideas???
 
Upvote 0
Hi Peter,
Well I for one am still a tad bit confused. I will try to restate your problem and you correct me if necessary.


A2 has a number from 1 to 10 and column B has a list of amounts from $1.00 to $10.00. If A2=3 then you want to return $6.00.


I think Aldin was right on track. Consider:

=SUM(B1:OFFSET(B1,A2,0))
 
Upvote 0
On 2002-05-08 06:05, Peter Adey wrote:
Thanks for the quick reply Rocky

The problem is I don't want sum up the values = A2 . I want to total the number of cells = A2. So,

IF a2= 9 then sum 9 cells etc, etc

any ideas???

Try what I suggested.
 
Upvote 0

Forum statistics

Threads
1,213,522
Messages
6,114,112
Members
448,549
Latest member
brianhfield

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top