Find the first positive number after deducting from a range of numbers VBA

Sotos13

New Member
Joined
Mar 8, 2019
Messages
42
Hi all
I have to find a way to solve this problem. I have a column with different numbers for example x1 x2 x3..x1000, and a specific range of 125 y1 y2 y3.. y125 numbers.
i want to find which x number is closest to a y number. So i was thinking to do y1-x1= and y2-x1= and y3- x1= and so on. the smallest positive number will be my correct answer. So in the below example the answer is 4848 and i want vba to bring me back in a specific column the Y number which in this case is 300000. Feel free to ask anything...waiting for some suggestions.


[TABLE="width: 192"]
<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl64, width: 64"]Y[/TD]
[TD="class: xl64, width: 64"]X[/TD]
[TD="class: xl64, width: 64"]Y-X[/TD]
[/TR]
[TR]
[TD="class: xl63"]282000[/TD]
[TD="class: xl63"]295152[/TD]
[TD="class: xl63"]-13152[/TD]
[/TR]
[TR]
[TD="class: xl63"]288000[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]-7152[/TD]
[/TR]
[TR]
[TD="class: xl63"]288000[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]-7152[/TD]
[/TR]
[TR]
[TD="class: xl63"]300000[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]4848[/TD]
[/TR]
[TR]
[TD="class: xl63"]300800[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]5648[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
I don't know how many rows/columns you got to deal but with your example:

Excel 2013/2016
ABC

<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]
[TD="align: right"]282000[/TD]
[TD="align: right"]295152[/TD]
[TD="align: right"]300000[/TD]

[TD="align: center"]2[/TD]
[TD="align: right"]288000[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]3[/TD]
[TD="align: right"]288000[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]4[/TD]
[TD="align: right"]300000[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]5[/TD]
[TD="align: right"]300800[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

</tbody>
Sheet1

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Array Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: #DAE7F5"]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: #DAE7F5"]C1[/TH]
[TD="align: left"]{=INDEX(A1:A10,MATCH(SMALL(ABS(A1:A10-B1),1),ABS(A1:A10-B1),0))}[/TD]
[/TR]
</tbody>[/TABLE]
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:
Upvote 0
Try this array formula:

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">X</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Y</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">RESULT</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">282000</td><td style="text-align:right; ">295152</td><td style="text-align:right; ">300000</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">288000</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:right; ">288000</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:right; ">300000</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="text-align:right; ">300800</td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Array Formula</td></tr><tr><td >C2</td><td >{=INDEX(A1:A6,MIN(IF(A2:A6-B2>0,ROW(A2:A6))))}</td></tr></table></td></tr></table>
 
Upvote 0
But if you prefer the macro, try this

Code:
Sub FormulaXY()
    lr = Range("A" & Rows.Count).End(xlUp).Row
    With Range("C2")
        .FormulaArray = "=INDEX(A1:A" & lr & ",MIN(IF(A2:A" & lr & "-B2>0,ROW(A2:A" & lr & "))))"
        .Value = .Value
    End With
End Sub
 
Upvote 0
Hi DanteAmor,
thanks for you help.
Your code works great!!!the only thing i didn't mention is that i need it to calculate all the values in column B with column A and return each one to column C. Now it works for one number.

As for the formula i tried it but it returns just the smallest value from column A(see example) {INDEX(F1:F7;MIN(IF(F2:F7-G2>0;ROW(F2:F7))))
[TABLE="width: 192"]
<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64, align: right"]282000[/TD]
[TD="width: 64, align: right"]295152[/TD]
[TD="width: 64, align: right"]282000[/TD]
[/TR]
[TR]
[TD="align: right"]288000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]288000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]300000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]300800[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]302400[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Hi Kokosek

Your formula is correct !!! thank you..Do you know how to write this formula in VBA?

No it is not. I've missed 'positive'.

Code:
=INDEX(M2:M6,MATCH(SMALL(IF(M2:M6-N2>0,M2:M6-N2,10^9),1),(M2:M6-N2),0))
 
Upvote 0
YES IT'S OK NOW THANKS..but why did you put 10^9...i'm trying to rephrase the meaning of all the function...
 
Upvote 0
As I am looking for smallest value (SMALL(array,1)), I would like to be sure that everything else what does not met IF condition will be really huge :-).
 
Upvote 0
Hi DanteAmor,
thanks for you help.
Your code works great!!!the only thing i didn't mention is that i need it to calculate all the values in column B with column A and return each one to column C. Now it works for one number.

As for the formula i tried it but it returns just the smallest value from column A(see example) {INDEX(F1:F7;MIN(IF(F2:F7-G2>0;ROW(F2:F7))))
[TABLE="width: 192"]
<tbody>[TR]
[TD="width: 64, align: right"]282000[/TD]
[TD="width: 64, align: right"]295152[/TD]
[TD="width: 64, align: right"]282000[/TD]
[/TR]
[TR]
[TD="align: right"]288000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]288000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]300000[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]300800[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]302400[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Is an array formula, To accept you must press Ctrl + Shift + Enter

{=INDEX(A1:A6,MIN(IF(A2:A6-B2>0,ROW(A2:A6))))}

-----

I pass the macro for the entire column C

Code:
Sub FormulaXY_2()
    lr = Range("A" & Rows.Count).End(xlUp).Row
    For i = 2 To lr
        With Range("C" & i)
            .FormulaArray = "=INDEX($A$1:$A$" & lr & ",MIN(IF($A$2:$A$" & lr & "-B" & i & ">0,ROW($A$2:$A$" & lr & "))))"
            .Value = .Value
        End With
    Next
End Sub




 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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