Sort A Linked Workbook

Innoguide

Board Regular
Joined
Sep 13, 2011
Messages
159
My main workbook Analyzer.xlsm links to another workbook called DataSource.xlsx

DataSource.xlsx is regularly updated and replaced so it needs to be sorted each time.

Both workbooks are in the same folder/location

Could anyone help with VBA that would run from Analyzer.xlsm to open DataSource.xlsx, sort it in descending order based on column E, save it and close it. Note that Row 1 in DataSource is a header.


Here's what I have below, but I need to make it relative so it will open the DataSource no matter the folder they are both in and also need to make it relative with regards to sorting the entire worksheet which will have a different number of rows each time:

Code:
Sub Externalsort()
    Workbooks.Open Filename:="C:\DataSource.xlsx"
    Cells.Select
    Application.CutCopyMode = False
    ActiveWorkbook.Worksheets("DataSource").Sort.SortFields.Clear
    ActiveWorkbook.Worksheets("DataSource").Sort.SortFields.Add2 Key _
        :=Range("E2:E11647"), SortOn:=xlSortOnValues, Order:=xlDescending, _
        DataOption:=xlSortNormal
    With ActiveWorkbook.Worksheets("DataSource").Sort
        .SetRange Range("B1:AM11647")
        .Header = xlYes
        .MatchCase = False
        .Orientation = xlTopToBottom
        .SortMethod = xlPinYin
        .Apply
    End With
    ActiveWorkbook.Save
    ActiveWindow.Close
End Sub


Any help is greatly appreciated!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Try this which assumes
- data headers start in A1
- both workbooks are in the same folder
- sheet name is "DataSource"
- wotrkbook name is "DataSource.xlsx"

paste into standard module in workbook "Analyzer.xlsm"
Code:
Sub OpenAndSort()
    Dim wb As Workbook, ws As Worksheet, rng As Range, kee As Range
    Set wb = Workbooks.Open(ThisWorkbook.Path & "\DataSource.xlsx")
    Set ws = wb.Sheets("DataSource")
    Set rng = ws.Range("A1").CurrentRegion
    Set kee = rng.Resize(, 1).Offset(, 4)
    
    ws.Sort.SortFields.Clear
    ws.Sort.SortFields.Add2 Key:=kee, SortOn:=xlSortOnValues, Order:=xlDescending, DataOption:=xlSortNormal
    With ws.Sort
        .SetRange rng
        .Header = xlYes
        .Orientation = xlTopToBottom
        .Apply
    End With

    wb.Close True
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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