Sort macro

Shadkng

Active Member
Joined
Oct 11, 2018
Messages
261
Hi, I recorded the macro to sort a range starting at A3 to column D, down to last row. I want to sort ascending in column C and then D. I changed the key:=Range("C3:C100" _ in line 6 & 8 to key:=Range("C3" _, and it seemed to work. However, I dont know what to do with the this on line 11: .SetRange Range("A3:D100") to not limit at 100. Thanks

VBA Code:
Sub SORT_TOT_FAB()
Application.ScreenUpdating = False
Range("A3:D3").Select
    Range(Selection, Selection.End(xlDown)).Select
    ActiveWorkbook.Worksheets("TOT FAB").Sort.SortFields.Clear
    ActiveWorkbook.Worksheets("TOT FAB").Sort.SortFields.Add2 key:=Range("C3:C100" _
        ), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
    ActiveWorkbook.Worksheets("TOT FAB").Sort.SortFields.Add2 key:=Range("D3:D100" _
        ), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
    With ActiveWorkbook.Worksheets("TOT FAB").Sort
        .SetRange Range("A3:D100")
        .Header = xlGuess
        .MatchCase = False
        .Orientation = xlTopToBottom
        .SortMethod = xlPinYin
        .Apply
    End With
    Range("E3").Select
    Application.ScreenUpdating = True
End Sub
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,614
Office Version
  1. 365
Platform
  1. Windows
Do you have a header row in row 3?
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,614
Office Version
  1. 365
Platform
  1. Windows
In that case, try
VBA Code:
Sub SORT_TOT_FAB()
   Application.ScreenUpdating = False
   With ActiveWorkbook.Worksheets("TOT FAB").Sort
      .SortFields.Clear
      .SortFields.Add2 Key:=Range("C3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
      .SortFields.Add2 Key:=Range("D3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
   
      .SetRange Range("A3:D" & .Parent.Range("A" & Rows.Count).End(xlUp).Row)
      .Header = xlNo
      .MatchCase = False
      .Orientation = xlTopToBottom
      .SortMethod = xlPinYin
      .Apply
   End With
   Range("E3").Select
   Application.ScreenUpdating = True
End Sub
This assumes you have data in col A for every row.
 
Solution

Shadkng

Active Member
Joined
Oct 11, 2018
Messages
261

ADVERTISEMENT

In that case, try
VBA Code:
Sub SORT_TOT_FAB()
   Application.ScreenUpdating = False
   With ActiveWorkbook.Worksheets("TOT FAB").Sort
      .SortFields.Clear
      .SortFields.Add2 Key:=Range("C3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
      .SortFields.Add2 Key:=Range("D3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
  
      .SetRange Range("A3:D" & .Parent.Range("A" & Rows.Count).End(xlUp).Row)
      .Header = xlNo
      .MatchCase = False
      .Orientation = xlTopToBottom
      .SortMethod = xlPinYin
      .Apply
   End With
   Range("E3").Select
   Application.ScreenUpdating = True
End Sub
This assumes you have data in col A for every row.
Perfect! Thanks
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,614
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Shadkng

Active Member
Joined
Oct 11, 2018
Messages
261

ADVERTISEMENT

Perfect! Thanks
Hi Fluff,

The below code is sorting by first digit, but I prefer to sort by number. I guess the ranges need to be formatted by number...I need to 2 places after the decimal for column C, no places for column D. And the range needs to be to the last row as it is now. Thanks again.

VBA Code:
Sub SORT_TOT_FAB()
   Application.ScreenUpdating = False
   With ActiveWorkbook.Worksheets("TOT FAB").Sort
      .SortFields.Clear
      .SortFields.Add2 key:=Range("C3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
      .SortFields.Add2 key:=Range("D3"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
      .SetRange Range("A3:D" & .Parent.Range("A" & Rows.Count).End(xlUp).Row)
      .Header = xlNo
      .MatchCase = False
      .Orientation = xlTopToBottom
      .SortMethod = xlPinYin
      .Apply
   End With
   Range("E3").Select
   Application.ScreenUpdating = True
End Sub
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,614
Office Version
  1. 365
Platform
  1. Windows
If col C & D contain text not numbers then you will need to convert them to numbers, simply changing the cell format won't make any difference.
 

Shadkng

Active Member
Joined
Oct 11, 2018
Messages
261
If col C & D contain text not numbers then you will need to convert them to numbers, simply changing the cell format won't make any difference.
Right now it comes up as general. When I change the format to number and run the macro it seems to sort the way I want it.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,614
Office Version
  1. 365
Platform
  1. Windows
Glad it's sorted & thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,129,685
Messages
5,637,803
Members
416,983
Latest member
LessThanAverageUser

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
Top