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:

CLCMCNCOCPCQCRCSCTCUCV
2TransferredConsultConsultAbandonedTransferredConsultCall EndedNULLNULLNULLNULL

<tbody>
</tbody>

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
 

Some videos you may like

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
7,997
Office Version
2019
Platform
Windows
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
 

el saxo

New Member
Joined
Aug 29, 2019
Messages
3
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. :biggrin:

So thanks very much for your reply because, without seeing it in your solution, I probably wouldn't have thought to try that!
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
7,997
Office Version
2019
Platform
Windows
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. :)
 

el saxo

New Member
Joined
Aug 29, 2019
Messages
3
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 :)
 

Forum statistics

Threads
1,089,467
Messages
5,408,430
Members
403,204
Latest member
pth

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top