Listing numbers appearing once in a range, then another column listing those occuring twice, then three etc...

welsh_philt

New Member
Joined
Jul 25, 2010
Messages
1
Hi,

I've an idea that would help me massively in work but I've no excel knowledge at all.

I've created a long column of numbers which can appear anywhere from once to seven times. I would like to create a table that has seven columns (cunningly entitled 'one appearance' to 'seven apperances') with the numbers that occur that many times listed below.

Is that possible?
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
Hi,

I've an idea that would help me massively in work but I've no excel knowledge at all.

I've created a long column of numbers which can appear anywhere from once to seven times. I would like to create a table that has seven columns (cunningly entitled 'one appearance' to 'seven apperances') with the numbers that occur that many times listed below.

Is that possible?
Here's one approach, though probably not the most compact. Column A is the list of numbers. Columns B:H segment the first occurrence of each number into one of the seven bins. Columns J:P gives a consolidated listing. Columns B:H can be hidden if you like. Adjust the ranges to accommodate the length of your list. In this example the list occupies A2:A150.
Excel Workbook
ABCDEFGHIJKLMNOP
1Numbers12345671234567
290   90   3114236  
Sheet2
 
Upvote 0
welsh_philt,


Excel Workbook
ABCD
11Unique Sorted NbrsCount
2217
3327
4432
5542
6651
7761
8171
92
101
112
121
132
141
152
161
172
181
192
203
214
22
Sheet1





The formula in cell C2 (confirmed with CTRL + SHIFT + ENTER ), copied down until it displays nothing:

=IF(ROWS($C$2:C2)>SUMPRODUCT(($A$1:$A$1000<>"")/COUNTIF($A$1:$A$1000,$A$1:$A$1000&"")),"",INDEX($A$1:$A$1000,MATCH(SMALL(IF(COUNTIF(OFFSET($A$1,0,0,ROW($A$1:$A$1000)-ROW($A$1)+1,1),$A$1:$A$1000)=1,COUNTIF($A$1:$A$1000,"<"&$A$1:$A$1000)),ROWS(C$2:$C2)),IF(COUNTIF(OFFSET($A$1,0,0,ROW($A$1:$A$1000)-ROW($A$1)+1,1),$A$1:$A$1000)=1,COUNTIF($A$1:$A$1000,"<"&$A$1:$A$1000)),0)))



The formula in cell D2 copied down:

=COUNTIF(A:A,C2)



If your list of numbers in column A goes beyound row 1000, then in cell C2, adjust the 1000's to a larger number.
 
Upvote 0
Hi,

I've an idea that would help me massively in work but I've no excel knowledge at all.

I've created a long column of numbers which can appear anywhere from once to seven times. I would like to create a table that has seven columns (cunningly entitled 'one appearance' to 'seven apperances') with the numbers that occur that many times listed below.

Is that possible?
Welcome to the MrExcel board!

Apart from the suggestions already made, I'm wondering if you really do need 7 columns for your results?

If you do, then perhaps the sort of layout in D1:K6 below might be some use. The formula in E2 is copied across and down.

If you don't, then maybe Excel's built-in Pivot Table feature (shown in D11:E18 below) might be useful.

Excel Workbook
ABCDEFGHIJK
1NumberAppearances->1234567
21Numbers ->1 1
3222
4533
5144
6355
75
84
92
103
111Count of Number
122NumberTotal
13414
14227
15233
16243
17252
181Grand Total19
193
204
21
Summary
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,826
Messages
6,121,793
Members
449,048
Latest member
greyangel23

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