Finding the position of the Nth match in an array with multiple criteria

el saxo

New Member
Joined
Aug 29, 2019
Messages
3
Hello all :) I hope someone can help me please, I've tried searching lots of sites for an answer but so far I haven't been successful...

In my worksheet, each row contains one of certain text values in columns CL to CV - either 'Transferred', 'Abandoned', 'Consult', 'Call Ended' or 'NULL', as illustrated below:

[TABLE="class: grid, width: 1000, align: center"]
<tbody>[TR]
[TD][/TD]
[TD]CL[/TD]
[TD]CM[/TD]
[TD]CN[/TD]
[TD]CO[/TD]
[TD]CP[/TD]
[TD]CQ[/TD]
[TD]CR[/TD]
[TD]CS[/TD]
[TD]CT[/TD]
[TD]CU[/TD]
[TD]CV[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Transferred[/TD]
[TD]Consult[/TD]
[TD]Consult[/TD]
[TD]Abandoned[/TD]
[TD]Transferred[/TD]
[TD]Consult[/TD]
[TD]Call Ended[/TD]
[TD]NULL[/TD]
[TD]NULL[/TD]
[TD]NULL[/TD]
[TD]NULL[/TD]
[/TR]
</tbody>[/TABLE]

Assuming column CL always contains 'Transferred', I want to find out the position (in this array) of the next column to contain EITHER 'Transferred' or 'Call Ended'. I.e. in the example above I would expect to return a 5 because column CP contains 'Transferred' and is the fifth column in the array CL:CV.

I can already find the position of the 'Nth' match based on a single criteria - for example if I just wanted to know the position of the next column after CL to contain 'Transferred' I would use this array formula:

{=SMALL(IF(CL2:CV2="Transferred",COLUMN(CL2:CV2)-COLUMN(CL2)+1),2)}

So, I tried introducing an 'OR' argument as shown below, but this doesn't work because it always returns a 2:

{=SMALL(IF(OR(CL2:CV2="Transferred",CL2:CV2="Call Ended"),COLUMN(CL2:CV2)-COLUMN(CL2)+1),2)}

With a bit of googling I think I've learned that 'OR' just doesn't work with SMALL IF, but this is where I'm stumped.

Can anyone help me solve this please? :confused:

Thanks
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
When you use OR it only gives a single result, not an array.

See if this one does what you need. Note that if you are in a country where you have to use ; instead of , then you might need to change the ; that is already in the formula to \

=AGGREGATE(15,6,COLUMN(CL2:CV2)/(CL2:CV2={"Transferred";"Call Ended"}),2)-COLUMN(CL2)+1
 
Upvote 0
When you use OR it only gives a single result, not an array.

See if this one does what you need. Note that if you are in a country where you have to use ; instead of , then you might need to change the ; that is already in the formula to \

=AGGREGATE(15,6,COLUMN(CL2:CV2)/(CL2:CV2={"Transferred";"Call Ended"}),2)-COLUMN(CL2)+1

Hi Jason, unfortunately that doesn't seem to work once it's copied down all rows - for example on a row containing 'Call Ended' in column CM (i.e. the 2nd column), it returns a 3.

However, it gave me an idea...

I swapped the 'OR' argument out of my original attempt and instead used semicolon-separated values in curly brackets (like you used in your AGGREGATE formula) for the conditional test of the IF statement, like so:

{=SMALL(IF(CL2:CV2={"Transferred";"Call Ended"},COLUMN(CL2:CV2)-COLUMN(CL2)+1),2)}

and it does exactly what I wanted because it returns an array of results instead of a single result. :grin:

So thanks very much for your reply because, without seeing it in your solution, I probably wouldn't have thought to try that!
 
Upvote 0
I don't see why one would work and not the other, aggregate(15,6 is exactly the same as {small(if(

I just tried 'Call Ended' in CM and it returned 2 as expected, the only exception should be is if CL didn't contain Transferred.

Not critical though, as long as you have something that does what you need it to, that's the important thing. :)
 
Upvote 0
I don't see why one would work and not the other, aggregate(15,6 is exactly the same as {small(if(

I just tried 'Call Ended' in CM and it returned 2 as expected, the only exception should be is if CL didn't contain Transferred.

Not critical though, as long as you have something that does what you need it to, that's the important thing. :)

Apologies, I just tried your formula again and compared the results, and you're quite right! I think I know what I did - I must have offset the formula by one row by mistake, i.e. pasted it in row 3. I blame a lack of caffeine... :wink:

Looks like both formulas are equally valid, and I can wrap them in an IF statement to handle any instances in my data where CM doesn't contain 'Transferred' (which I'm not interested in anyway).

Thanks again for your help :)
 
Upvote 0

Forum statistics

Threads
1,223,898
Messages
6,175,274
Members
452,628
Latest member
dd2

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