Help nesting isna check into array formula

suitcase_livin

New Member
Joined
Sep 2, 2014
Messages
6
{=INDEX(Comparables_data!$A$2:$AV$252,(MATCH($D$1&A11,Comparables_data!$AG$2:$AG$252&Comparables_data!$C$2:$C$2525,0)),13)}

<tbody>
</tbody>

Hi friends, new to MrExcel and also to array formulas. I have put together a working index match array and just need help nesting an isna.

Above is my formula.. I want the isna to return a "--" if there is no match. I just cant figure out where to place the if and isna functions. Please help!
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
If you have Excel 2007 or higher, you could just do this:

=IFERROR(INDEX(Comparables_data!$A$2:$AV$252,(MATCH($D$1&A11,Comparables_data!$AG$2:$AG$252&Comparables_data!$C$2:$C$2525,0)),13),"--")
 
Upvote 0
Hi.

I take it you're using Excel 2003 or earlier then, and so can't take advantage of Excel's more concise IFERROR, i.e.:

=IFERROR(INDEX(Comparables_data!$A$2:$AV$252,MATCH($D$1&A11,Comparables_data!$AG$2:$AG$252&Comparables_data!$C$2:$C$2525,0),13),"--")

If so, then you'll need the longer ISNA approach that you mention:

=IF(ISNA(INDEX(Comparables_data!$A$2:$AV$252,MATCH($D$1&A11,Comparables_data!$AG$2:$AG$252&Comparables_data!$C$2:$C$2525,0),13)),"--",INDEX(Comparables_data!$A$2:$AV$252,MATCH($D$1&A11,Comparables_data!$AG$2:$AG$252&Comparables_data!$C$2:$C$2525,0),13))

However, I should also point out that the only reason that this formula needs to be entered as an array formula is because you are performing the concatenation of the two columns in Comparables_data within the formula itself.

If would be much better, unless your set-up does not at all allow you to do so, to use an extra column in the Comparables_data tab in which to perform these concatenations.

Not only will that remove the not inconsiderable resource required by Excel to perform the concatenations within the formulas themselves (I presume this formula is being copied to further cells and is not just a one-off) but, more importantly, it will mean that this formula no longer needs to be committed as an array formula.

And if you are on Excel 2003, then since this ISNA set-up effectively requires that large, resource-heavy array formula - in cases where there is no error - to be calculated not just once, but twice, then the need to avoid unnecessary calculation becomes even more important.

Don't get me wrong - if you're new to array formulas then you're to be commended on producing such a formula, which is syntactically perfect. It's just that there are times for array formulas, and times for non-array formulas. And this may be a case for the latter.

Regards
 
Last edited:
Upvote 0
To add another point to the IFERROR formula, Excel 2013 has a more specific IFNA formula that works the same way as IFERROR, but only for an N/A error.
 
Upvote 0
For the record, I am using Excel 2010 and don't know how all my googling never fruited the iferror function. I will try first thing in the morning when I get back to my office and report back.

you fellas are too kind, wish there was a way to repay you apart from internet gratitude!!!
 
Upvote 0
I will also look into the suggestion to concatenation on my source data tab rather than within the formula!


Thanks for the heads up about the Ifna function too!
 
Upvote 0
You're welcome, although it sounds like it won't be helpful in your case, since you're on 2010.
 
Upvote 0

Forum statistics

Threads
1,213,492
Messages
6,113,967
Members
448,537
Latest member
Et_Cetera

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