Please Note: This article is written for users of the following Microsoft Excel versions: , 8, , 10, and . If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Putting Addresses on State-Specific Worksheets.

Putting Addresses on State-Specific Worksheets

by Allen Wyatt
(last updated February 4, 2016)

Linda has a worksheet containing 250 addresses from all over the country. She wants to separate the addresses, by state, to different worksheets so that each worksheet contains addresses only from a specific state.

There is no way to do this with any of the built-in Excel functions or wizards. This is probably a reflection of the fact that most people leave the data on a single worksheet, and then use various Excel tools (such as filtering) to display only a subset of the overall data.

If you want to copy state-specific information to separate sheets, however, you can do so manually by using AutoFilter. This works particularly well if you have only a few states in your sources data. Just apply an AutoFilter and display only those rows that are in the state you want to copy. Select the visible rows, copy them, and paste them to a new worksheet. Repeat the process with each of the other states in your original data set.

If you have data for quite a few sheets, you can copy it by automating this process. The following macro will use the AutoFilter capabilities of Excel to copy the information to a new worksheet. It does this for each unique value in the state column, which is specified by the iCol variable. (In this example, iCol is set to 5, which means that the states are in column E.)

Sub NewSheetEachAutofilter()
    Dim wOri As Worksheet
    Dim wks As Worksheet
    Dim wPT As Worksheet
    Dim bAutoFilter As Boolean
    Dim PT As PivotTable
    Dim rPT As Range
    Dim rCell As Range
    Dim iCol As Integer
    Dim sHeader As String

    On Error GoTo Errhandler
    Application.ScreenUpdating = False
    iCol = 5 'Filter all on Col E

    Set wOri = ActiveSheet
    With wOri
        'Save Autofilter status
        bAutoFilter = .AutoFilterMode
        If Not bAutoFilter Then 'turn on autofilter
            .Range("a1").AutoFilter
        End If
        If .FilterMode Then .ShowAllData

        'use a PivotTable on a temp
        'sheet to get a unique list
        Set PT = .PivotTableWizard _
          (SourceType:=xlDatabase, _
          SourceData:=.Range("a1").CurrentRegion, _
          TableDestination:="", _
          TableName:="PivotTable1")
        sHeader = .Cells(1, iCol)
        With PT
            .AddFields RowFields:=sHeader
            .PivotFields(sHeader).Orientation = xlDataField
            .ColumnGrand = False
        End With
        Set wPT = ActiveSheet
        With wPT
            Set rPT = .Range(.Range("A3"), _
              .Cells(.Cells.Rows.Count, 1).End(xlUp))
        End With

        'loop through unique list
        For Each rCell In rPT
            .Range("a1").AutoFilter Field:=iCol, _
              Criteria1:=rCell.Value
            'create new sheet and name it with the state
            Set wks = Worksheets.Add
            wks.Name = rCell.Value
            .AutoFilter.Range.Copy wks.Range("A1")
        Next
        .ShowAllData
        .Select
    End With
    Application.DisplayAlerts = False
    wPT.Delete

ExitHandler:
    Application.DisplayAlerts = True
    Application.ScreenUpdating = True
    'remove filter if no previous one
    If Not bAutoFilter Then
        wOri.AutoFilterMode = False
    End If
    Set rCell = Nothing
    Set rPT = Nothing
    Set PT = Nothing
    Set wOri = Nothing
    Set wks = Nothing
    Set wPT = Nothing
    Exit Sub

Errhandler:
    MsgBox Err.Number & ":" & Err.Description
    Resume ExitHandler
End Sub

The code may look complex because of its length, but it isn't particularly difficult. It makes sure that the AutoFilter is turned on, and then it creates a PivotTable based on your original data. This PivotTable is used to gather the list of states from the data. Each state is then used on the original data as a filtering criteria. The filtered information is then copied to a new worksheet that is named using the state.

The macro does not modify the original data. If you prefer to have the original data deleted after it is moved to a worksheet, then all you need to do is add a single line of code. Add this line right after the line that deletes the PivotTable (wPT.Delete):

wOri.Delete

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3383) applies to Microsoft Excel , 8, , 10, and . You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Putting Addresses on State-Specific Worksheets.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Saving in MS-DOS Text Mode

Over the years Microsoft has made changes in Word. One change is to the import and export filters provided with the various ...

Discover More

Displaying the First Worksheet in a Macro

When creating macros, you often have to know how to display individual worksheets. VBA provides several ways you can display ...

Discover More

Renaming a Style

Styles are invaluable when it comes to applying consistent formatting in and across documents. If you need to rename a style ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

MORE EXCELTIPS (MENU)

Three-Dimensional Transpositions

Excel makes it easy to transpose your data so that rows become columns and columns rows. It doesn?t have a built-in ...

Discover More

Selecting a Word

There are a few editing tricks you can apply in Excel the same as you do in Word. Selecting a word from the text in a cell is ...

Discover More

Cell Movement After Enter

What happens when you press Enter in a cell depends on how you have Excel configured. Here's the way you can control the ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)