Switching between formulas

Rainmanne

Board Regular
Joined
Mar 10, 2016
Messages
134
Office Version
  1. 2019
Platform
  1. Windows
I need to switch between 4 formulas based on 4 criteria. The criteria are in two fields (2 criteria in each). I handle it using the IF statement, but the whole formula is so cumbersome:

Excel Formula:
=IF($D5="IS",IF($E5="Direct",INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)),-INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0))),IF($D5="BS",IF($E5="Direct",INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0))-OFFSET(INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)),,-1),OFFSET(INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)),,-1)-INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)))))

So basically, it goes as follows:

IF it's "IS" and "Direct", the values are taken as they are
IF it's "IS" and "Reverse", the values change the sign (from + to - or vice versa)
IF it's "BS" and "Direct", it is current value minus previous value
IF it's "BS" and "Reverse", it's previous value minus current value

Don't mind the INDEX MATCH construction, I am going to change it to a different formula. It's just so difficult to change the formula and to understand it after a few months from the time it's created so I wonder if it's possible to use some logical function instead of the IF expression. Unfortunately I cannot upload a spreadsheet example due to restrictions.
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
You could try it like
Excel Formula:
=IF($D5="IS",INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0))*(IF($E5="Direct",1,-1)),IF($D5="BS",INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)+(IF($E5="Direct",0,-1)))-INDEX(FS!$1:$1048576,MATCH($A5,FS!$B:$B,0),MATCH(G$1,FS!$1:$1,0)+(IF($E5="Direct",-1,0)))))
 
Upvote 0
Solution
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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