New tabs based on content

wmtsub

Active Member
Joined
Jun 20, 2018
Messages
322
Is it possible to search thru a colum, say "E", and for each matching entry cut the entire row for each entry and paste them to a new tab. So if colum "E" had ten entires with the word "Ball" all ten rows would now be moved to a new tab called "Ball", then the same for "BAT", "Glove" etc for all entries so ther would be noo more lines on the initial tab and dozens of tabs?
 

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.
try this. It lets you enter the word you want to search in column E.

Code:
Sub t()
Dim txt As String, sh1 As Worksheet, sh2
txt = InputBox("Enter the key word to search for.", "KEY WORD")
Set sh1 = ActiveSheet
Set sh2 = Sheets.Add
sh2.Name = txt
    With sh1
        .UsedRange.AutoFilter 5, txt
        .UsedRange.Offset(1).SpecialCells(xlCellTypeVisible).EntireRow.Copy sh2.Cells(Rows.Count, 1).End(xlUp)(2)
        .AutoFilterMode = False
    End With
End Sub
 
Upvote 0
This will do what you want I think, creates a new tab for every word and copies across.

Just change Sheets("Data") to your sheet name

It does assume you have headings for your data and want them copied also

Code:
Sub createtabsandmove()


Dim rownum As Long
Dim rownum2 As Long
Dim mystr As String
Dim mysh As Worksheet
Dim ws As Worksheet
Dim lastrow As Long
Dim counter As Long


Set mysh = ActiveWorkbook.Sheets("Data")
lastrow = mysh.Cells(mysh.Rows.Count, "E").End(xlUp).Row
rownum = 2
rownum2 = 2
mystr = 0
counter = 0


Do Until WorksheetFunction.CountA(mysh.Range("E2:E999999")) = 0
    Do Until rownum = lastrow + 1


    If mysh.Cells(rownum, 5).Value = "" Then
    GoTo nextrow
    End If
    
    If mysh.Cells(rownum, 5).Value <> "" And counter = 0 Then
    mystr = mysh.Cells(rownum, 5).Value
    Set ws = ThisWorkbook.Sheets.Add(After:= _
        ThisWorkbook.Sheets(ThisWorkbook.Sheets.Count))
    ws.Name = mystr
    mysh.Rows(1).Copy ws.Rows(1)
    counter = 1
    End If


    If mysh.Cells(rownum, 5).Value = mystr Then
    mysh.Rows(rownum).Copy ws.Rows(rownum2)
    mysh.Rows(rownum).ClearContents
    rownum2 = rownum2 + 1
    End If


nextrow:
    rownum = rownum + 1
    Loop


rownum2 = 2
rownum = 2
counter = 0
Loop


End Sub
 
Last edited:
Upvote 0
mrshl9898,
Thank you for the code. It almost works perfectly!!!!! Seems I have an issue with special charectors when naming the tabs.
I will need to find some way to strip / \ etc.

Appreciate the start..thanks
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,884
Members
452,364
Latest member
springate

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