If Array Formula returning the entire "True" Value for each True result

Dave12

New Member
Joined
Dec 3, 2020
Messages
2
Office Version
  1. 365
It's been a few months since I've last used an Array formula and I consider myself fairly well versed in them, but I can't figure this one out!

The array is fairly simple and I've identified the issue is with the IF section returning multiple values for each "True" result, instead of the expected single number so I'm only going to review that portion.

{=SMALL(IF(Sheet19!$C$2:$P$2=0,ROW($1:$14)),ROW($1:$1))}

Stepping through the formula I get to this stage:
Formula1 (2).png


The result I'd normally expect from this would be 1,2,3,4,5,6,7,8,9,10,11,12,, of which the small is currently picking the 1st smallest number.

However the evaluation is not working as I'd expect and giving the following on the next step

Formula2 (2).png



Any help appreciated!
 

Some videos you may like

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
10,739
Welcome to the MrExcel forum!

That's because you're comparing columns (C2:P2) with rows (ROW(1:14)). Excel will turn that into a 2-D array. Commas separate columns, semi-colons separate rows, and you can see those in the Evaluate Formula box. You'd probably want to do something like:

Excel Formula:
{=SMALL(IF(Sheet19!$C$2:$P$2=0,COLUMN($C:$P)-2),1)}
 
Solution

Dave12

New Member
Joined
Dec 3, 2020
Messages
2
Office Version
  1. 365
Brilliant - thank you Eric!

It hadn't occurred to me that I'd never done a horizontal Array before!
 

Watch MrExcel Video

Forum statistics

Threads
1,127,009
Messages
5,622,143
Members
415,880
Latest member
Bruce0203

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
Top