Consulting

Results 1 to 9 of 9

Thread: Filter and Sort with Multiple Headers

  1. #1

    Filter and Sort with Multiple Headers

    Good afternoon,

    I have been reading that this is frowned upon but I have the following setup in a excel spreadsheet and would like to be able to sort it without having the 2nd Header included in the Sort and being moved through out the spreadsheet.

    I want to be able to Sort using the Client Name Header. I cannot move the Bottom header above the top header, which everyone is telling me to do. Is there a way to Filter and Sort using the top header without causing the bottom header to move?

    excel_sort.jpg

  2. #2
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,711
    Location
    Move row 2 above row 1, sort row 2-n, and then put the new row 1 back where it started as row 2
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  3. #3
    VBAX Regular
    Joined
    Mar 2012
    Posts
    32
    Location
    Hide the second row > sort > unhide

  4. #4
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,711
    Location
    Maybe simpler


    Sub Macro1()
        Dim r As Range
        
        Set r = ActiveSheet.Cells(1, 1).CurrentRegion
        Set r = r.Cells(3, 1).Resize(r.Rows.Count - 1, r.Columns.Count)
        
        With ActiveSheet.Sort
            .SortFields.Clear
            .SortFields.Add Key:=r.Columns(2), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
            .SetRange r
            .Header = xlNo
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With
    End Sub
    
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  5. #5
    Hi,

    I tried this and it keeps putting the 2nd header at the bottom of the sort once done.

    Quote Originally Posted by Paul_Hossler View Post
    Maybe simpler


    Sub Macro1()
        Dim r As Range
        
        Set r = ActiveSheet.Cells(1, 1).CurrentRegion
        Set r = r.Cells(3, 1).Resize(r.Rows.Count - 1, r.Columns.Count)
        
        With ActiveSheet.Sort
            .SortFields.Clear
            .SortFields.Add Key:=r.Columns(2), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
            .SetRange r
            .Header = xlNo
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With
    End Sub
    

  6. #6
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,711
    Location
    Probably because 1) I can't count, and 2) I didn't have a good enough test case

    Set r = r.Cells(3, 1).Resize(r.Rows.Count - 2, r.Columns.Count)

    Option Explicit
    
    Sub Macro1()
        Dim r As Range
        
        Set r = ActiveSheet.Cells(1, 1).CurrentRegion
        Set r = r.Cells(3, 1).Resize(r.Rows.Count - 2, r.Columns.Count)
        
        With ActiveSheet.Sort
            .SortFields.Clear
            .SortFields.Add Key:=r.Columns(2), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
            .SetRange r
            .Header = xlNo
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With
    End Sub
    
    Attached Images Attached Images
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  7. #7
    VBAX Regular
    Joined
    Mar 2012
    Posts
    32
    Location
    Hi, pawcoyote
    Did you try my method in post #3?

  8. #8
    Yes, I can do that but that isn't what I want to be able to do. I want to be able to sort from the first header without having to change anything. I know my structure isn't the best but you would think you could do this easily..
    Quote Originally Posted by akuini View Post
    Hi, pawcoyote
    Did you try my method in post #3?

  9. #9
    Thank you very much for all your help!
    Quote Originally Posted by Paul_Hossler View Post
    Probably because 1) I can't count, and 2) I didn't have a good enough test case

    Set r = r.Cells(3, 1).Resize(r.Rows.Count - 2, r.Columns.Count)

    Option Explicit
    
    Sub Macro1()
        Dim r As Range
        
        Set r = ActiveSheet.Cells(1, 1).CurrentRegion
        Set r = r.Cells(3, 1).Resize(r.Rows.Count - 2, r.Columns.Count)
        
        With ActiveSheet.Sort
            .SortFields.Clear
            .SortFields.Add Key:=r.Columns(2), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
            .SetRange r
            .Header = xlNo
            .MatchCase = False
            .Orientation = xlTopToBottom
            .SortMethod = xlPinYin
            .Apply
        End With
    End Sub
    

Posting Permissions

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