Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Condensing Sequential Values to a Single Row.

Condensing Sequential Values to a Single Row

by Allen Wyatt
(last updated June 18, 2016)

7

Rusty has a list of ZIP Codes in a column of a worksheet. He would like a way to "compress" the codes so that sequential ranges of values are on a single row. So, for instance, instead of 35013, 35014, and 35015 taking up three rows, they would appear on a single row as 35013-35015.

There are a couple of ways to go about this—with or without macros. On the "without macros" side of the fence, there are a number of different approaches, and all of them involve the use of additional columns to hold intermediate results.

For example, let's assume that you have your data in column A, starting in cell A2, and that cell A1 is empty (it doesn't even have header text in it). In this case you could enter the following formula in cell B2:

=IF(NOT(A2-A1=1),A2,IF(A3-A2=1,B1,A2)) 

Then, in cell C2, enter the following long formula:

=IF(NOT(A3-A2=1),IF(A2-A1=1,TEXT(B1,"00000")
&" - "&TEXT(B2,"00000"),TEXT(A2,"00000")),"")

Now you can copy the formulas in cells B2:C2 down their respective columns. What you end up with in column C is the condensed series of ZIP Codes. You can copy these values—using Paste Special to ignore blank cells—to anyplace else you want.

If you want to use a macro approach, then there are no intermediate columns necessary. A macro can be written that essentially collapses the list of ZIP Codes in place. The following macro loops through whatever range of cells you selected and creates the condensed list:

Sub CombineValues()
    Dim rng As Range
    Dim rCell As Range
    Dim sNewArray() As String
    Dim x As Long
    Dim y As Long
    Dim sStart As String
    Dim sEnd As String

    Set rng = Selection
    sStart = rng.Cells(1)
    sEnd = sStart
    y = 1
    For x = 1 To rng.Count - 1
        If rng.Cells(x + 1) - _
          rng.Cells(x) > 1 Then  'End
            ReDim Preserve sNewArray(1 To y)
            If sStart = sEnd Then
                sNewArray(y) = sStart
            Else
                sNewArray(y) = sStart & "-" & sEnd
            End If
            sStart = rng.Cells(x + 1)
            y = y + 1
        End If
        sEnd = rng.Cells(x + 1)
        ReDim Preserve sNewArray(1 To y)
        If sStart = sEnd Then
            sNewArray(y) = sStart
        Else
            sNewArray(y) = sStart & "-" & sEnd
         End If
    Next
    rng.ClearContents
    For x = 1 To y
        rng.Cells(x) = "'" & sNewArray(x)
    Next
    Set rng = Nothing
    Set rCell = Nothing
End Sub

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11977) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Condensing Sequential Values to a Single Row.

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

Converting Codes to Characters

Character codes are the numeric values used, by a computer, to signify various alphanumeric characters. You can use the ...

Discover More

Breaking a Document Link

Word allows you to link external information into your documents. If you no longer need to maintain the active link, you ...

Discover More

Excel 2013 Filters and Filtering (Table of Contents)

Excel provides two ways to filter your data so that only what you want to see is displayed. Discover how filtering works ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Locating a Single-Occurrence Value in a Column

Given a range of cells containing values, you may have a need to find the first value in the range that is unique. This ...

Discover More

Reordering Last Name and First Name

If you've got a list of names in a column, you may want to change the order of each name. For instance, the name have the ...

Discover More

Searching for a Value Using a Function

Searching for a value using Excel's Find tool is easy; searching for that same value using a formula or a macro is more ...

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

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 7 + 5?

2019-09-15 01:25:26

Frederick Rothstein

Not sure what happened with the output on my last message, but here is the (much shorter) macro that I just post (hopefully, without all of the extra blank lines)...

Sub CombineValues()
Dim N As Long, Data As Variant, Temp As Variant, Series As Variant
Data = Selection.Resize(Selection.Count + 1).Value
ReDim Temp(1 To UBound(Data))
Temp(1) = Data(1, 1)
For N = 2 To UBound(Data) - 1
If Data(N - 1, 1) + 1 = Data(N, 1) Then
If Data(N, 1) + 1 <> Data(N + 1, 1) Then Temp(N) = -Data(N, 1) & ","
Else
Temp(N) = Data(N, 1) & ","
End If
Next
Series = Split(Trim(Replace(Replace(Replace(Join(Temp), " ", ""), ",-", "-"), ",", " ")))
Selection.ClearContents
Selection.Resize(UBound(Series) + 1) = Application.Transpose(Series)
End Sub


2019-09-15 01:20:37

Frederick Rothstein

Here is a macro (much shorter than the one you posted) that I believe works correctly all of the time...

Sub CombineValues()

Dim N As Long, Data As Variant, Temp As Variant, Series As Variant

Data = Selection.Resize(Selection.Count + 1).Value

ReDim Temp(1 To UBound(Data))

Temp(1) = Data(1, 1)

For N = 2 To UBound(Data) - 1

If Data(N - 1, 1) + 1 = Data(N, 1) Then

If Data(N, 1) + 1 <> Data(N + 1, 1) Then Temp(N) = -Data(N, 1) & ","

Else
Temp(N) = Data(N, 1) & ","

End If

Next

Series = Split(Trim(Replace(Replace(Replace(Join(Temp), " ", ""), ",-", "-"), ",", " ")))

Selection.ClearContents

Selection.Resize(UBound(Series) + 1) = Application.Transpose(Series)

End Sub


2019-09-15 01:14:40

Frederick Rothstein

Allen - your macro does not seem to work reliably. It yields the wrong result for this list...

12345
12346
12347
98765
98766
98767
24680
24681
24682
24683
34981
34982
34983
48765
48766
48767


2016-07-20 06:43:05

Michael (Micky) Avidan

I Forgot the main issue - NO HELPER COLUMN REQUIRED !!!
...and: folloeing, should be: following
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2017)
ISRAEL


2016-07-20 06:40:39

Michael (Micky) Avidan

Some say that I sometimes have trouble to understand problems.
If this is not such a case - I would love to hear your opinion regarding the solution shown in the folloeing picture.
(see Figure 1 below)
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2017)
ISRAEL


Figure 1. 




2016-07-19 17:11:14

Austin Brister

Do you have a similar tool for a selection in Word of a comma delineated list?


2016-06-19 01:24:33

Nir Liberman

Same result, half the length:
B2: =IF(A2=A1+1,B1,A2)
C2: =IF(B2=B3,"",TEXT(B2,"00000")&IF(B2=B1," - " & TEXT(A2,"00000"),""))

for sorted (asc) list only.


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

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

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.