VBA array to sort and display information

dimsums

New Member
Joined
Jun 29, 2020
Messages
31
Office Version
  1. 365
Platform
  1. Windows
Hi all,
I have a sheet with information and i use the sort method to display the information i would like to see on top. This works for a few but sometimes displays the sort results in rows 2000 onwards instead of displaying it on top.
Could someone help me see why?

Sub ofinumber()
'
' ofinumber Macro
'

'
ActiveWindow.ScrollColumn = 13
ActiveWindow.ScrollColumn = 12
ActiveWindow.ScrollColumn = 9
ActiveWindow.ScrollColumn = 1
ActiveWindow.SmallScroll Down:=-18
Range("Cf5").Select
Selection.Copy
Range("k1").Select
ActiveSheet.Paste
Range("A3:AP2774").Select
Application.DeleteCustomList ListNum:=11
Application.AddCustomList ListArray:=Array("OFI", ".", "PI", "6S", "HS", "NC", "CC" _
, "SF", "MAINT")
ActiveWorkbook.Worksheets("All OFIs").Sort.SortFields.Clear
ActiveWorkbook.Worksheets("All OFIs").Sort.SortFields.Add Key:=Range( _
"G3:G2774"), SortOn:=xlSortOnValues, Order:=xlAscending, CustomOrder:= _
"OFI,.,MS,6S,HS,NC,CC,SF,MAINT", DataOption:=xlSortNormal
ActiveWorkbook.Worksheets("All OFIs").Sort.SortFields.Add Key:=Range( _
"a3:a2774"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
xlSortNormal
ActiveWorkbook.Worksheets("All OFIs").Sort.SortFields.Add Key:=Range( _
"E3:E2774"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
xlSortNormal
With ActiveWorkbook.Worksheets("All OFIs").Sort
.SetRange Range("A2:AP2774")
.Header = xlYes
.MatchCase = False
.Orientation = xlTopToBottom
.SortMethod = xlPinYin
.Apply
End With
ActiveWindow.ScrollRow = 3
Rows("3:2774").Select
Rows("3:2774").EntireRow.AutoFit
ActiveCell.Offset(1, 0).Select
Do While Not IsEmpty(ActiveCell)
ActiveCell.Offset(1, 0).Select
Loop
End Sub
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Try this:

VBA Code:
Sub ofinumber()
  Dim arr As Variant
  Dim lr As Long
  Dim sh As Worksheet
  
  Set sh = ActiveWorkbook.Worksheets("All OFIs")
  arr = Array("OFI", ".", "PI", "6S", "HS", "NC", "CC", "SF", "MAINT")
  Application.DeleteCustomList ListNum:=11
  Application.AddCustomList ListArray:=arr
  
  Range("CF5").Copy Range("K1")
  lr = Range("A" & Rows.Count).End(3).Row
  
  With sh.Sort
    .SortFields.Clear
  
    .SortFields.Add Key:=sh.Range("G3:G" & lr), SortOn:=0, Order:=1, CustomOrder:=Join(arr, ","), DataOption:=0
    .SortFields.Add Key:=sh.Range("A3:A" & lr), SortOn:=0, Order:=1, DataOption:=0
    .SortFields.Add Key:=sh.Range("E3:E" & lr), SortOn:=0, Order:=1, DataOption:=0
    
    .SetRange sh.Range("A2:AP" & lr)
    .Header = xlYes
    .MatchCase = False
    .Orientation = xlTopToBottom
    .SortMethod = xlPinYin
    .Apply
  End With
  
  sh.Rows("3:" & lr).EntireRow.AutoFit
  sh.Range("A" & lr).Select
End Sub
 
Upvote 0
Solution
Thanks Dante,
I also realised that my referencing was off and that fixed the code.
Thank you for your help!
 
Upvote 0
Well there you have an improved code for your consideration.
 
Upvote 0

Forum statistics

Threads
1,213,535
Messages
6,114,198
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