Sort sheets by cell value

rsutton1981

New Member
Joined
Mar 9, 2016
Messages
47
Office Version
  1. 365
Platform
  1. Windows
Hi, I have some code that I modified from another thread. The code is to sort sheets based on a specific cell number on the sheet. My sheets are called "QM03-P1-R1" where the P and R number can be modified. The sheets are continually being created but not in a specific number. When I run the code it will sort in to P1, P1001, P1002, P11, P1102, P1851, P2, P201. Where I need it as P1, P2, P11, P201 P1001, etc. Can anyone help modify the code to help.

The code is below

Code:
Dim WorkRng As Range
Dim WorkAddress As String
On Error Resume Next
xTitleId = "Sheet Sort"
Set WorkRng = Application.Selection
Set WorkRng = Application.InputBox("Type D1", xTitleId, WorkRng.Address, Type:=8)
WorkAddress = WorkRng.Address
Application.ScreenUpdating = False
For i = 4 To Application.Worksheets.Count
    For j = i To Application.Worksheets.Count
        If VBA.UCase(Application.Worksheets(j).Range(WorkAddress)) < VBA.UCase(Application.Worksheets(i).Range(WorkAddress)) Then
            Application.Worksheets(j).Move Before:=Application.Worksheets(i)
        End If
    Next
Next
Application.ScreenUpdating = True
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
I do not understand very well how you "have based on a specific cell number on the sheet".
But the next macro is going to order the sheets if their name starts with the letters "QM"
Test and comment.

Code:
Sub Ordenar_Hojas()
'Por Dante Amor
    '
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    Set h = Sheets.Add
    fila = 1
    For i = 1 To Sheets.Count
        If Left(Sheets(i).Name, 2) = "QM" Then
            nums = Split(Sheets(i).Name, "-")
            n1 = Mid(nums(1), 2)
            n2 = Mid(nums(2), 2)
            h.Cells(fila, "A").Value = Val(n1)
            h.Cells(fila, "B").Value = Val(n2)
            h.Cells(fila, "C").Value = Sheets(i).Name
            fila = fila + 1
        End If
    Next
    u = h.Range("A" & Rows.Count).End(xlUp).Row
    With h.Sort
        .SortFields.Clear
        .SortFields.Add Key:=h.Range("A1:A" & u), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
        .SortFields.Add Key:=h.Range("B1:B" & u), SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
        .SetRange h.Range("A1:C" & u)
        .Header = xlGuess
        .MatchCase = False
        .Orientation = xlTopToBottom
        .SortMethod = xlPinYin
        .Apply
    End With
    For i = 1 To u
        hoja = h.Cells(i, "C").Value
        Sheets(hoja).Move After:=Sheets(Sheets.Count)
    Next
    h.Delete
    Application.ScreenUpdating = True
    Sheets(1).Select
    MsgBox "Fin"
End Sub


Regards Dante Amor
 
Upvote 0
Hi Dante,

you are a genius.

Works excellently.

thanks very much
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,917
Members
452,366
Latest member
TePunaBloke

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