conditional range

AJBB

New Member
Joined
May 20, 2020
Messages
2
Office Version
  1. 2013
Platform
  1. Windows
I need to create a range between B5:M5 that is defined by the location of P1 (phase 1) and P2 (phase 2) in Row 4. The range should begin one column to the right and one row down from P1 and end at the cell one column to the left and one row down from P2.

P1 and P2 are both movable and so moving them left/right should make longer/shorter ranges depending on which cells in row 4 they are moved to. P1 is always to the left of P2.

In example 1 the locations of P1 and P2 give a range a range of 8 cells in row 5. All cells in this range bar the final cell should be 80% of A5 (highlighted in blue) divided by the number of cells in the range bar the final cell. I.e. =SUM($A$5*80%/7) because there are 7 cells in the 8-cell range not including the final cell. The final cell in the range (K5) should be 20% of A5. All values in the range D5:K5 sum to 100% of A5.

In example 2, P1 and P2 are moved closer together, giving a range in row 9 of 4 cells. The first 3 cells should be 80% of A9 divided equally across the 3 cells E9:G9, and the final cell H9 should be 20% of A9.

I'm struggling to write a formula to apply to B5:M5 in example 1 and B9:M9 in example 2 which achieves the above, advice would be really appreciated, thank you.


excel1.JPG
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
This should do what you're asking for,
Cell Formulas
RangeFormula
B5:M5B5=IF(AND(COLUMNS($B5:B5)>MATCH("P1",$B$4:$M$4,0),COLUMNS($B5:B5)<MATCH("P2",$B$4:$M$4,0)),IF(C4="P2",$A5*20%,$A5*80%/(MATCH("P2",$B$4:$M$4,0)-MATCH("P1",$B$4:$M$4,0)-2)),"")
B7:M7B7=IF(AND(COLUMNS($B7:B7)>MATCH("P1",$B$6:$M$6,0),COLUMNS($B7:B7)<MATCH("P2",$B$6:$M$6,0)),IF(C6="P2",$A7*20%,$A7*80%/(MATCH("P2",$B$6:$M$6,0)-MATCH("P1",$B$6:$M$6,0)-2)),"")
 
Upvote 0
This works perfectly, thank you very much! Now I need to study how this formula works...
 
Upvote 0

Forum statistics

Threads
1,223,723
Messages
6,174,123
Members
452,546
Latest member
Rafafa

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