Allocating Closest Match Numbers? VBA

JumboCactuar

Well-known Member
Joined
Nov 16, 2016
Messages
785
Office Version
  1. 365
Platform
  1. Windows
Hi,
if i have the following data (columns A-C):

NameDefaultNoAllocated
John51
Jim88
Tom33
Luke56
Paul56
Frank49
Bob49
James38
Trevor56

and column F

Available No
29-A
29-B
30-A
30-B
30-C
32-D
35-A
41-A
42-A
43-B
44-A
48-A
49-A
49-B
49-C
49-D
51-D
57-E
57-G
58-A
60-A
71-B

i want to allocate the closest available and then remove it from list
e.g if DefaultNo is 51
look through Available closest to 51 and take it from the list
repeat down

expected result:

NameDefaultNoAllocated
John5151-D
Jim8871-B
Tom3332-D
Luke5657-E
Paul5657-G
Frank4949-A
Bob4949-B
James3841-A
Trevor5658-A

any help appreciated
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
try this code:
VBA Code:
Sub test()
Dim numb As Long

lastrow = Cells(Rows.Count, "A").End(xlUp).Row
inarr = Range(Cells(1, 1), Cells(lastrow, 3))
lastavail = Cells(Rows.Count, "F").End(xlUp).Row
avail = Range(Cells(1, 6), Cells(lastavail, 6))
  For i = 2 To lastrow
  Delta = 1E+20
  indi = 0
   For j = 2 To lastavail
    numb = Left(avail(j, 1), 2)
    tempdel = inarr(i, 2) - numb
    If tempdel < 0 Then tempdel = -tempdel
    If tempdel < Delta Then
     Delta = tempdel
     indi = j
    End If
    Next j
    inarr(i, 3) = avail(indi, 1)
    avail(indi, 1) = "00-AA"
  Next i
Range(Cells(1, 1), Cells(lastrow, 3)) = inarr
 

End Sub
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
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