Copy Top 10 Values With Corresponding Names Into Another Sheet Excel VBA

taccoo73

New Member
Joined
Feb 14, 2014
Messages
21
Hi All;

First of all, thanks again for your time and help in advance. Here I am with another issue which I’m failing to see where the problem is.

Code below finds the highest 10 values in a range (column I) and copies them into another sheet. Part with the top 10 values and copying them is working nicely. But when I’m trying to bring the corresponding names for those values (column B) I’m hitting the wall. Code below says “Object Variable or With Block Variable not set”.

Code:
Sub top10()
 
Dim rngValues As Range
Dim rngNames As Range
Dim i As Integer
Dim r As Integer
Dim j As Long
Dim lrow As Long
Dim l As String
 
Dim rptdate As String
Dim CIOfile As String
Stop
rptdate = Range("B3")
CIOfile = "CIO Mng" & " " & rptdate & ".xlsm"
 
Set rngValues = Workbooks(CIOfile).Sheets("Rep").Range("I11:I310")
 
l = 0
j = 0
r = 19
 
For i = 1 To 10
 
    j = Application.WorksheetFunction.Large(rngValues, i)
    Set rngNames = rngValues.Find(j)
    lrow = rngNames.Row
    l = Cells(lrow, "B").Value
    Cells(r, "H") = j
    Cells(r, "G") = l
    r = r + 1
Next i
 
End Sub

Any help will be appreciated.

Kind Regards;

tac
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Try
Code:
Sub top10()
 
Dim rngValues As Range
Dim rngNames As Range
Dim i As Integer
Dim r As Integer
Dim j As Long
Dim lrow As Long
Dim l As String
 
Dim rptdate As String
Dim CIOfile As String
Stop
rptdate = Range("B3")
CIOfile = "CIO Mng" & " " & rptdate & ".xlsm"
 
Set rngValues = Workbooks(CIOfile).Sheets("Rep").Range("I11:I310")
 
l = 0
j = 0
r = 19
 
For i = 1 To 10
 
    j = Application.WorksheetFunction.Large(rngValues, i)
    Set rngNames = rngValues.Find(j, , , xlWhole)
    Cells(r, "H") = j
    Cells(r, "G") = rngNames.Offset(, -7)
    r = r + 1
Next i
 
End Sub
 
Upvote 0
Hi Fluff;

Thanks a lot for your time, appreciate it!

Still giving the same error “Object Variable or With Block Variable not set”. rngNames remains as "Nothing"
 
Upvote 0
If the corresponding values in Column B are on the same sheet as the top 10, then you need to qualify where:

Code:
    l = Workbooks(CIOfile).Sheets("Rep").Cells(lrow, "B").Value
 
Upvote 0
Hi Fluff;

Thanks a lot for your time, appreciate it!

Still giving the same error “Object Variable or With Block Variable not set”. rngNames remains as "Nothing"

Which line gives the error?
And what are the values in RngValues?
 
Last edited:
Upvote 0
Code:
[COLOR=#333333]Cells(r, "G") = rngNames.Offset(, -7)[/COLOR]
this is the line with the error, when I check it with F8 in code/break, I can see that rngNames=Nothing.

Values in rngValues are numbers (column I), in current example from 36000 to 11000. Corresponding names are on column B, in the same sheet.
 
Upvote 0
Are the numbers the result of a formula?
 
Upvote 0
Not sure if this will make any difference, but change this Dim as shown
Code:
Dim j As [COLOR=#0000ff]Double[/COLOR]
 
Upvote 0
Found it!

Code:
Set rngNames = rngValues.Find(j, , xlFormulas, xlWhole)
makes it work. Tried to find the value 36000 by using Ctrl+F manually on the source sheet and I saw that excel cannot find it as Value, it was able to find when I change it to Formulas. Apparently values in pivot tables are not values after all.

Thank you very much for your time and help Fluff!
 
Upvote 0

Forum statistics

Threads
1,214,832
Messages
6,121,841
Members
449,051
Latest member
excelquestion515

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