Count Unique Values based on 1 or 2 criteria

Dom10

New Member
Joined
Jan 4, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
I am trying to count the unique values based on 1 or 2 criteria. As per the example below, in column F I want to count the unique Drawing Numbers for each Package. In column G I want to count the unique drawing numbers per package which are also approved. Any help would be greatly appreciated.

1617720230337.png
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Can you post some sample data to the board.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
406785-MMD-CWD-00-ZZ-RG-000008.xlsx
ABCDEFG
1Drawing NumberPackageStatusPacakgeUnique DrawingsApproved
2D/AAA/0001S1ApprovedS133
3D/AAA/0001S1ReceivedS221
4D/AAA/0001S1Rejected
5D/AAA/0002S1Approved
6D/AAA/0003S1Approved
7D/AAA/0003S1Rejected
8D/AAA/0003S1Rejected
9D/BBB/0001S2Approved
10D/BBB/0002S2Rejected
Sheet3


How's this?
 
Upvote 0
Try:

Book1 (version 1).xlsb
ABCDEFGHIJK
1Drawing NumberPackageStatusPackageUnique DrawingsApprovedPackageUnique DrawingsApproved
2D/AAA/0001S1ApprovedS133S133
3D/AAA/0001S1ReceivedS221S221
4D/AAA/0001S1Rejected
5D/AAA/0002S1Approved
6D/AAA/0003S1Approved
7D/AAA/0003S1Rejected
8D/AAA/0003S1Rejected
9D/BBB/0001S2Approved
10D/BBB/0002S2Rejected
Sheet19
Cell Formulas
RangeFormula
E2:E3E2=SORT(UNIQUE(B2:B10))
F2:F3F2=ROWS(UNIQUE(FILTER(A$2:A$10,B$2:B$10=E2)))
G2:G3G2=ROWS(UNIQUE(FILTER(A$2:A$10,(B$2:B$10=E2)*(C$2:C$10=G$1))))
I2:I3I2=UNIQUE(B2:B10)
J2:J3J2=TRANSPOSE(MMULT(SEQUENCE(,ROWS(A2:A10),,0),(MATCH(A2:A10,A2:A10,0)=ROW(A2:A10)-ROW(A2)+1)*(B2:B10=TRANSPOSE(I2#))))
K2:K3K2=TRANSPOSE(MMULT(SEQUENCE(,ROWS(A2:A10),,0),(MATCH(A2:A10,A2:A10,0)=ROW(A2:A10)-ROW(A2)+1)*(B2:B10=TRANSPOSE(I2#))*(C2:C10=K1)))
Dynamic array formulas.


The F2 and G2 formulas you have to drag down. I came up with some Spill formulas for those in J2 and K2, but they're pretty ugly. I think you're better off with F2 and G2.
 
Upvote 0
Try:

Book1 (version 1).xlsb
ABCDEFGHIJK
1Drawing NumberPackageStatusPackageUnique DrawingsApprovedPackageUnique DrawingsApproved
2D/AAA/0001S1ApprovedS133S133
3D/AAA/0001S1ReceivedS221S221
4D/AAA/0001S1Rejected
5D/AAA/0002S1Approved
6D/AAA/0003S1Approved
7D/AAA/0003S1Rejected
8D/AAA/0003S1Rejected
9D/BBB/0001S2Approved
10D/BBB/0002S2Rejected
Sheet19
Cell Formulas
RangeFormula
E2:E3E2=SORT(UNIQUE(B2:B10))
F2:F3F2=ROWS(UNIQUE(FILTER(A$2:A$10,B$2:B$10=E2)))
G2:G3G2=ROWS(UNIQUE(FILTER(A$2:A$10,(B$2:B$10=E2)*(C$2:C$10=G$1))))
I2:I3I2=UNIQUE(B2:B10)
J2:J3J2=TRANSPOSE(MMULT(SEQUENCE(,ROWS(A2:A10),,0),(MATCH(A2:A10,A2:A10,0)=ROW(A2:A10)-ROW(A2)+1)*(B2:B10=TRANSPOSE(I2#))))
K2:K3K2=TRANSPOSE(MMULT(SEQUENCE(,ROWS(A2:A10),,0),(MATCH(A2:A10,A2:A10,0)=ROW(A2:A10)-ROW(A2)+1)*(B2:B10=TRANSPOSE(I2#))*(C2:C10=K1)))
Dynamic array formulas.


The F2 and G2 formulas you have to drag down. I came up with some Spill formulas for those in J2 and K2, but they're pretty ugly. I think you're better off with F2 and G2.
Mr Eric! Thanks very much. The F2 and G2 formulae are great. Sorry it has taken me so long to respond, I have only just got around to implementing the solution.
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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