Consulting

Results 1 to 5 of 5

Thread: Selecting and sorting variable range

  1. #1

    Selecting and sorting variable range

    Hello,

    I am kind of new to this and very basic knowledge of VBA, so I apologize if my questions are trivial. I generally just record my macros and then I can do some basic edits, but I am kind of stuck with this one.

    I am trying to select a range of cells and sort it. The selection will always start in cell A4 and end in column G; the number or rows will vary. I don't want to put a set range of A4:G10000 (some large number) because I have a summary row, that I am trying to exclude from the sort. So my last row needs to be the one before where A doesn't have any value.

    Regarding the sort: this one I just recorded the macro and wanted to use that, but it is referencing the name of the Worksheet and my Worksheet names will always be different, so I just want it to work on the current active sheet.

    This is the code for the moment:

    Range("A4:G44").Select
    ActiveWorkbook.Worksheets("DOWNLOAD7").Sort.SortFields.Clear
    ActiveWorkbook.Worksheets("DOWNLOAD7").Sort.SortFields.Add Key:=Range( _
    "B4:B44"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
    xlSortNormal
    With ActiveWorkbook.Worksheets("DOWNLOAD7").Sort
    .SetRange Range("A4:G44")
    .Header = xlGuess
    .MatchCase = False
    .Orientation = xlTopToBottom
    .SortMethod = xlPinYin
    .Apply
    End With

    I am using Excel 2007.

    Thank you,

    Radka

  2. #2
    Moderator VBAX Guru Simon Lloyd's Avatar
    Joined
    Sep 2005
    Location
    UK
    Posts
    3,003
    Location
    Try:
    Range("A4:G" & range("A" & rows.count).end(xlup).row).Select
        Activesheet.Sort.SortFields.Clear
        Activesheet.Sort.SortFields.Add Key:=Range( _
            "B4:B44"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
            xlSortNormal
        With Activesheet.Sort
            .SetRange Range("A4:G" & range("A" & rows.count).end(xlup).row)
            .Header = xlGuess
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With
    Regards,
    Simon
    Please read this before cross posting!
    In the unlikely event you didn't get your answer here try Microsoft Office Discussion @ The Code Cage
    If I have seen further it is by standing on the shoulders of giants.
    Isaac Newton, Letter to Robert Hooke, February 5, 1675 English mathematician & physicist (1642 - 1727)

  3. #3
    Perfect! Thank you so much!!!

  4. #4
    Sorry, one more question: 4th line is still referencing a set number of rows:

    ActiveSheet.Sort.SortFields.Add Key:=Range( _
    "B4:B44"), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
    xlSortNormal

    Isn't that going to be a problem if I have more or less rows?

  5. #5
    VBAX Expert
    Joined
    Aug 2004
    Posts
    810
    Location
    you can apply Simon's principle / extrapolate / by example:
        lastrow = Range("A" & Rows.Count).End(xlUp).Row
        Range("A4:G" & lastrow).Select
        ActiveSheet.Sort.SortFields.Clear
        ActiveSheet.Sort.SortFields.Add Key:=Range( _
            "B4:B" & lastrow), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:= _
            xlSortNormal
        With ActiveSheet.Sort
            .SetRange Range("A4:G" & lastrow)
            .Header = xlGuess
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •