Finding the Number of Columns Between Two Values

dskexcel

New Member
Joined
Mar 4, 2015
Messages
48
Hello,

I need to find the number of cells between the second and third values. Below is an example:

ABCDEFGH
5215
899

<tbody>
</tbody>

So, for row 2, I'd like the formula to return an answer of 3. For row 3, I'd like it to return 2. I have two other columns that help a little by providing the values of the second and third values (for instance I2 would show "2" and J2 shows 15). With these extra columns that identify the second and third values, I used this formula with some success: =ABS(MATCH(I2, (A2:H2, 0)-MATCH(J2, A2:H2, 0)).

However, that formula does not work with A3:H3 from my example. The reason is because the second and third values are the same (9 and 9), therefore cells I3 and J3 are the same.

Thanks in advance!
 
Last edited:

Excel Facts

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

I can do a VBA User-Defined Function. Any good?

Paste the following code into a new Module then you will have a new worksheet function called Test. Just give Test the range to be examined. For example:
=Test(A1:H1)
then drag the formula down.

Code:
Function Test(r As Range) As Variant
    Dim i As Long
    Dim bln1 As Boolean
    Dim col2 As Long
    For i = 1 To r.Count
        If r(1, i).Value <> "" Then
            If col2 > 0 Then
                Test = i - col2
                Exit Function
            End If
            If bln1 And col2 = 0 Then col2 = i
            If Not bln1 Then bln1 = True
        End If
    Next
    Test = CVErr(xlErrNA)
End Function
 
Upvote 0
Perhaps:

=SUM(SMALL(IF(ISNUMBER(A1:H1),COLUMN(A1:H1)),{3,2})*{1,-1})

Confirm with CTRL-SHIFT-ENTER rather than just Enter
 
Last edited:
Upvote 0
It looks good to me, Scott.

I thought Arrays, I could visualize a list of Trues and Falses ...
Then I ran out of brain-power. :)

I really must get the hang of this worksheet stuff!

Neat solution.

Regards,
 
Upvote 0
Thank you both for the solutions! Rick, I'm not a VBA guy so I'm going to use Scott's solution, but thanks for the efforts.

Scott - your formula works great, thanks!
 
Upvote 0

Forum statistics

Threads
1,213,530
Messages
6,114,163
Members
448,554
Latest member
Gleisner2

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