Tabs from filtered range

cuetipper

Board Regular
Joined
Nov 9, 2018
Messages
67
I need help please. Cant get this to work.
I am activating the auto filter.
I would like a text box to request the column such as a or b or c
Then for the list of possible filtered entries in that column loop thru each and copy paste results to a new sheet named for that filter.
So in the example below if I choose column c i will get 4 additional sheets label b, c, j, t each with the visible results if filtered by that name.


Order_IdAppointment_DateInspector
928205/13/2022 09:00:00b
973806/22/2022 13:30:00c
983106/24/2022 09:00:00c
978206/25/2022 13:30:00b
978306/25/2022 15:30:00b
978506/29/2022 13:30:00f
988806/29/2022 15:30:00c
NXT988106/30/2022 09:00:00t
NXT985807/01/2022 13:30:00t
NXT985507/01/2022 15:30:00t
NXT994507/01/2022 15:30:00j
NXT984807/05/2022 13:30:00t
NXT978607/05/2022 15:30:00t
NXT986907/05/2022 15:30:00j
NXT988707/06/2022 13:30:00t
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Note:
For column B the sheet name format will be: "mm-dd-yyyy hh-mm-ss"

Try this:

VBA Code:
Sub create_worksheets()
  Dim c As Range, sh As Worksheet, ky As Variant
  Dim col As Variant
  
  Application.ScreenUpdating = False
  
  col = Application.InputBox("Enter column: A, B or C")
  If col = "" Then Exit Sub
  If UCase(col) = "A" Or UCase(col) = "B" Or UCase(col) = "C" Then
    Set sh = ActiveSheet
    With CreateObject("scripting.dictionary")
      For Each c In sh.Range(sh.Cells(2, col), sh.Cells(Rows.Count, col).End(xlUp))
        If c.Value <> "" Then
          .Item(c.Value) = c.Value
        End If
      Next c
      For Each ky In .Keys
        If UCase(col) = "B" Then
          sh.Range("A1").AutoFilter Field:=Columns(col).Column, Operator:=xlFilterValues, Criteria2:=Array(4, Format(ky, "mm/dd/yyyy hh:mm:ss"))
          Sheets.Add(, Sheets(Sheets.Count)).Name = Format(ky, "mm-dd-yyyy hh-mm-ss")
        Else
          sh.Range("A1").AutoFilter Columns(col).Column, ky
          Sheets.Add(, Sheets(Sheets.Count)).Name = ky
        End If
        sh.AutoFilter.Range.EntireRow.Copy Range("A1")
      Next ky
    End With
    sh.Select
    sh.ShowAllData
  End If

  Application.ScreenUpdating = True
End Sub


-----------------
NOTE XL2BB:
For the future, it would help greatly if you could give us the sample data in a form that we can copy to test with.
MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in
Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0

Forum statistics

Threads
1,215,052
Messages
6,122,878
Members
449,097
Latest member
dbomb1414

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