Number Ranges/Series

duffy01

New Member
Joined
Jan 27, 2010
Messages
5
Hi All,

I'm trying to get a set of data into a certain format, automatically:

In Column A I have the following type of data -

3
4
5
6
9
11
14
15
16
17
33
37

1) I want to return the consecutive number series with less than 3 numbers like: 1,2

2) I also want to return the consecutive number series with 3 or more numbers like: 14-17

3) Then, I want the output of the data to be separated by commas.

4) That result would then be put in parentheses.

5) A count of the numbers would then appear before the parentheses.

The end result of the above example data would look like:

12 (3-6,9,11,14-17,33,37)

Can anyone help?

Thanks in advance!

Duff
 

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Hi, This could possibly be a lot simpler , but it seems to work.

Code:
[COLOR="Navy"]Sub[/COLOR] MG28Jan37
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, txt [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String,[/COLOR] c
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
c = c + 1
[COLOR="Navy"]If[/COLOR] c = 1 And Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR] txt = txt & Dn
[COLOR="Navy"]If[/COLOR] c = 1 And Not Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR] txt = txt & Dn & ","
[COLOR="Navy"]If[/COLOR] Not c = 1 [COLOR="Navy"]Then[/COLOR]
    [COLOR="Navy"]If[/COLOR] Not Dn.Offset(1) = Dn + 1 And Dn.Offset(-1) + 1 = Dn [COLOR="Navy"]Then[/COLOR]
        txt = txt & "-" & Dn & ","
    [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]If[/COLOR] Dn.Offset(1) = Dn + 1 And Not Dn.Offset(-1) + 1 = Dn [COLOR="Navy"]Then[/COLOR]
        txt = txt & Dn
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]If[/COLOR] Not Dn.Offset(-1) + 1 = Dn And Not Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR]
        txt = txt & Dn & ","
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] Dn
MsgBox Rng.Count & " (" & txt & ")"
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 

duffy01

New Member
Joined
Jan 27, 2010
Messages
5
Mick,

This works fantastic for the example I gave.

How do I get it to work on a bigger range of numbers?
(i.e. cell A1 to A400)?

Thx

Duff
 

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Hi, The code should work for as many rows as you have filled with numbers in column "A", But you will end up with a rather large Msgbox.
What would you like to do with the result, put them in a range somewhere ???
Regards Mick
 

duffy01

New Member
Joined
Jan 27, 2010
Messages
5
Yes.. I need to return that msgbox data into a cell (the last number can't have a comma after it though)

Thanks... you rule!!

Duff

*Preferably cell B1.. thx!!
 
Last edited:

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Hi, Remove the magbox bit & replace with the code below.
Code:
txt = Left(txt, Len(txt) - 1)
[COLOR="Navy"]With[/COLOR] Range("b1")
    .Value = Rng.Count & " (" & txt & ")"
    .WrapText = True '[COLOR="Green"][B] remove this if not wanted[/B][/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
Regards Mick
 

duffy01

New Member
Joined
Jan 27, 2010
Messages
5
Mick,

This works 99.8% (which is a lot more than I had!)

If I have two consecutive numbers only, it puts a dash there.

I need anything less than 2 to be commas, and anything 3 or more to be the dash.

Thanks for all your help so far... this is incredible!!

Duff
 

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Hi, Duff, Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG29Jan17
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, txt [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String,[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer,[/COLOR] n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer,[/COLOR] com
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
c = c + 1
[COLOR="Navy"]If[/COLOR] c = 1 And Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR] txt = txt & Dn
[COLOR="Navy"]If[/COLOR] c = 1 And Not Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR] txt = txt & Dn & ","
[COLOR="Navy"]If[/COLOR] Not c = 1 [COLOR="Navy"]Then[/COLOR]
    [COLOR="Navy"]If[/COLOR] Not Dn.Offset(1) = Dn + 1 And Dn.Offset(-1) + 1 = Dn [COLOR="Navy"]Then[/COLOR]
        txt = txt & "-" & Dn & ","
    [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]If[/COLOR] Dn.Offset(1) = Dn + 1 And Not Dn.Offset(-1) + 1 = Dn [COLOR="Navy"]Then[/COLOR]
        txt = txt & Dn
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]If[/COLOR] Not Dn.Offset(-1) + 1 = Dn And Not Dn.Offset(1) = Dn + 1 [COLOR="Navy"]Then[/COLOR]
        txt = txt & Dn & ","
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] Dn
txt = Left(txt, Len(txt) - 1)
    com = Split(txt, ",")
[COLOR="Navy"]For[/COLOR] n = 0 To UBound(com)
    [COLOR="Navy"]If[/COLOR] InStr(com(n), "-") > 0 [COLOR="Navy"]Then[/COLOR]
        [COLOR="Navy"]If[/COLOR] Val(Split(com(n), "-")(0) + 1) = Val(Split(com(n), "-")(1)) [COLOR="Navy"]Then[/COLOR]
            com(n) = Replace(com(n), "-", ",")
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] n
[COLOR="Navy"]With[/COLOR] Range("b1")
    .Value = Rng.Count & " (" & Join(com, ",") & ")"
    .WrapText = True '[COLOR="Green"][B] remove this if not wanted[/B][/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 

Forum statistics

Threads
1,082,276
Messages
5,364,196
Members
400,786
Latest member
ismi88

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top