VBA To Find Last Row & Cell, Select Additional Columns, Format and Sort

mjd

Board Regular
Joined
Feb 23, 2010
Messages
73
Hello,

I am working on a project that will have a variable range of rows that I will need to sort the data and format the entire range. Columns B-G will always have data in them, but I need to be able to sort columns A-I, regardless of data included in columns A, H, & I.

Now, using the macro recorder I have been able to do it for a fixed range, but I will need to make this work for anything between 25 and 5000 rows depending on the day.

Essentially, I need to find the last row of column G, select the cell in column I of that row, and then select the range of a4:I, apply all borders, and sort by columns E then B.

Here is the fixed range code where the last data point is in G27:

Code:
Sub Test()
    Range("B4").Select
    Range(Selection, Selection.End(xlDown)).Select
    Range(Selection, Selection.End(xlToRight)).Select
    Selection.End(xlDown).Select
    Selection.End(xlToRight).Select
    Range("I27").Select
    Range(Selection, Selection.End(xlToLeft)).Select
    Range(Selection, Selection.End(xlToLeft)).Select
    Range(Selection, Selection.End(xlToLeft)).Select
    Range(Selection, Selection.End(xlUp)).Select
    Selection.Borders(xlDiagonalDown).LineStyle = xlNone
    Selection.Borders(xlDiagonalUp).LineStyle = xlNone
    With Selection.Borders(xlEdgeLeft)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    With Selection.Borders(xlEdgeTop)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    With Selection.Borders(xlEdgeBottom)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    With Selection.Borders(xlEdgeRight)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    With Selection.Borders(xlInsideVertical)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    With Selection.Borders(xlInsideHorizontal)
        .LineStyle = xlContinuous
        .ColorIndex = 0
        .TintAndShade = 0
        .Weight = xlThin
    End With
    ActiveWorkbook.Worksheets("Sheet1").Sort.SortFields.Clear
    ActiveWorkbook.Worksheets("Sheet1").Sort.SortFields.Add Key:=Range("E4:E27") _
        , SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
    ActiveWorkbook.Worksheets("Sheet1").Sort.SortFields.Add Key:=Range("B4:B27") _
        , SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
    With ActiveWorkbook.Worksheets("Sheet1").Sort
        .SetRange Range("A3:I27")
        .Header = xlYes
        .MatchCase = False
        .Orientation = xlTopToBottom
        .SortMethod = xlPinYin
        .Apply
    End With
End Sub

I for the life of me cannot get a dynamic range to select beyond row 4 in my sample set. Any thoughts would be greatly appreciated. I feel like I might be over complicating what needs to be done, but I can't see where.

Thanks,
Mike
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Mike

You rarely have to select anything to work with it in vba and selecting slows you code considerably. Selecting is just one area where the macro recorder, while useful, does not produce optimum code.

Try this on a copy of your workbook.

Code:
Sub Testv2()
  With Range("A4:I" & Range("G" & Rows.Count).End(xlUp).Row)
    .BorderAround LineStyle:=xlContinuous
    .Borders(xlInsideVertical).LineStyle = xlContinuous
    .Borders(xlInsideHorizontal).LineStyle = xlContinuous
    .Sort Key1:=.Columns("E"), Order1:=xlAscending, Key2:=.Columns("B"), Order2:=xlAscending, _
                Header:=xlNo, OrderCustom:=1, MatchCase:=False, Orientation:=xlTopToBottom, DataOption1:=xlSortNormal, DataOption2:=xlSortNormal
  End With
End Sub
 
Upvote 0
Thank you, Peter! That worked like a charm. Greatly appreciate the help on this!

All the best,
Mike

Mike

You rarely have to select anything to work with it in vba and selecting slows you code considerably. Selecting is just one area where the macro recorder, while useful, does not produce optimum code.

Try this on a copy of your workbook.

Code:
Sub Testv2()
  With Range("A4:I" & Range("G" & Rows.Count).End(xlUp).Row)
    .BorderAround LineStyle:=xlContinuous
    .Borders(xlInsideVertical).LineStyle = xlContinuous
    .Borders(xlInsideHorizontal).LineStyle = xlContinuous
    .Sort Key1:=.Columns("E"), Order1:=xlAscending, Key2:=.Columns("B"), Order2:=xlAscending, _
                Header:=xlNo, OrderCustom:=1, MatchCase:=False, Orientation:=xlTopToBottom, DataOption1:=xlSortNormal, DataOption2:=xlSortNormal
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,171
Members
453,021
Latest member
Justyna P

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