sum unique/total items on one sheet and put values on anothe

robfritts

New Member
Joined
Apr 28, 2002
Messages
18
I've got a lot of data on a particular spread sheet (lots of them actually) and am interested in calculating some basic stats on it. I would like to have a formula or macro examine each sheet and tell me the number of total items (lines of data - 1 for the heading) and the number of total UNIQUE items for a particular column.

I'm not sure if this is further complicated by the fact that there are 500-1000+ lines that are empty. To eliminate the headers/footers from the external report, I ran a FOR/NEXT loop to ClearContents of a row if a cell's criteria matched certain things. I thought about deleting the row, but that would make my FOR/NEXT loop skip every other row when one was deleted (& renumbered). I'm thinking about redoing my routine to axe those header/footer lines, but haven't given it much thought yet.

One possible (albeit ugly) solution would be to take Mr.Excel's Table of Contents example and just extrapolate it to get those values for both unique/non-unique pages then do the math to calculate how many lines per page to get a rough estimate.

Another solution I've thought of, again pretty ugly, would be to step through each cell of a column, set the string value to the new cell value and compare to the old string value, if different then sum, if same them next row... something like that...

Your suggestion on this would be greatly appreciated.
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Suppose we have the following columns of data in columns A and B with labels in row 1 in Sheet1:

{"Field1","Field2";
1,"ak";
2,"";
3,"ab";
4,"zet";
"","";
5,"";
6,""}

where "" stands for blank cells.
Notice that column A is of numeric type and B of alphanumeric type.

In a sheet called e.g., Overview,

In A2 enter:

=MATCH(9.99999999999999E+307,Sheet1!A:A)

This gives you the size of the used range in column A of Sheet1.

In A3 enter:

=COUNT(OFFSET(Sheet1!A2,0,0,A2-1,1))

This gives you a count of numeric data (including real 0's) in column A of Sheet1.

In A4 enter:

=SUM(IF(FREQUENCY(OFFSET(Sheet1!A2,0,0,A2-1,1),OFFSET(Sheet1!A2,0,0,A2-1,1)),1))

This gives you a count of unique numbers in column A of Sheet1.

In B2 enter:

=MATCH(REPT("z",40),Sheet1!B:B)

This gives you the size of the used range in column B of Sheet1.

In B3 enter:

=COUNTA(OFFSET(Sheet1!B2,0,0,B2-1,1)) or

=COUNTIF(OFFSET(Sheet1!B2,0,0,B2-1,1),"<>")

This gives you a count of alphanumeric/textual data (including formula-generated blanks if any exists) in column B of Sheet1.

In B4 array-enter:

=SUM(IF(LEN(OFFSET(Sheet1!B2,0,0,B2-1)),1/COUNTIF(OFFSET(Sheet1!B2,0,0,B2-1,1),OFFSET(Sheet1!B2,0,0,B2-1,1))))

This gives you a count of unique alphanumeric/textual entries (exluding formula-generated blanks if they exist) in column B of Sheet1.

Note 1. In order to array-enter a formula, you need to hit control+shift+enter, not just enter.

Note 2. If a target column is of mixed data type, use the second set of formula in such cases.

Aladin
 
Upvote 0

Forum statistics

Threads
1,213,565
Messages
6,114,338
Members
448,570
Latest member
rik81h

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