Create / Consolidate Data Range from Full Values

andrewgroom

New Member
Joined
May 7, 2009
Messages
21
Hi,

I have tried to find an answer to this but to no avail.

I am trying to condense a full list of values into ranges (and there isn't necessarily a pattern). E.g.

Column 1Column 2
11
21
31
42
52
63
73
83
94

<tbody>
</tbody>

Would become:

Column 1Column 2
1-31
4-52
6-83
94

<tbody>
</tbody>


Thank you in advance!

Cheers,
A
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
Hi Andrew,

Assuming that your example is presented in cells A1:B10 (i.e. row 1 is a header, rows 2-10 are values), you can use the following formulas in columns D&E:

Cell E2 - array formula - enter with Ctrl+Shift+Enter:
Code:
=IFERROR(INDEX($B$2:$B$10,MATCH(0,COUNTIF($E$1:E1,$B$2:$B$10),0)),"")

Cell D2 - array formula - enter with Ctrl+Shift+Enter:
Code:
=IFERROR(INDEX($A$2:$A$10,MATCH($E2,$B$2:$B$10,0))&"-"&INDEX($A$2:$A$10,MAX(IF($B$2:$B$10=$E2,ROW($B$2:$B$10)))-1),"")

Now drag & drop both formulas into the remaining cells (D3:E10).

Hope it helps.
 
Upvote 0
Thank you so much! This worked perfectly! I expanded it to cover ranges of values of over 1000 rows (and replicated across multiple columns) and it worked just as I needed.

I really appreciate your time taken to respond.

Cheers,
A
 
Upvote 0
I understand that you already have a suitable solution, but in case it is of interest to you, in columns D:E below are some alternative formulas that do not require the Ctrl+Shift+Enter confirmation.
Column C also contains another alternative in case you want the single value, as you gave in your sample in post 1, where relevant.

Excel Workbook
ABCDE
1Column 1Column 2RangeRangeValue
2111-31-31
3214-54-52
4316-86-83
54299-94
652
763
873
983
1094
Ranges
 
Upvote 0
You're welcome Andrew.

And Peter, many thanks for sharing! It's great to learn something new.
 
Upvote 0
or without any formula but with PowerQuery aka Get&Transform (if you are able to use it):

Column1Column2RangeColumn2
1​
1​
1-3
1​
2​
1​
4-5
2​
3​
1​
6-8
3​
4​
2​
9-9
4​
5​
2​
6​
3​
7​
3​
8​
3​
9​
4​

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    GRP = Table.Group(Source, {"Column2"}, {{"Count", each _, type table}}),
    Record1 = Table.AddColumn(GRP, "Custom", each Table.First([Count])),
    Expand1 = Table.ExpandRecordColumn(Record1, "Custom", {"Column1"}, {"Column1"}),
    Record2 = Table.AddColumn(Expand1, "Custom", each Table.Last([Count])),
    Expand2 = Table.ExpandRecordColumn(Record2, "Custom", {"Column1"}, {"Column1.1"}),
    Merge = Table.CombineColumns(Table.TransformColumnTypes(Expand2, {{"Column1", type text}, {"Column1.1", type text}}, "en-GB"),{"Column1", "Column1.1"},Combiner.CombineTextByDelimiter("-", QuoteStyle.None),"Range"),
    ROC = Table.SelectColumns(Merge,{"Range", "Column2"})
in
    ROC[/SIZE]
 
Upvote 0
Thank you all for your responses!! Very interesting and I love that there are so many different approaches to finding a solution. You all rock!
 
Upvote 0
Thank you all for your responses!! Very interesting and I love that there are so many different approaches to finding a solution. You all rock!
Glad to contribute to your options. :)
 
Upvote 0

Forum statistics

Threads
1,213,522
Messages
6,114,112
Members
448,549
Latest member
brianhfield

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