+ Reply to Thread
Results 1 to 4 of 4

Counting Unique combinations of two variables

  1. #1
    Registered User
    Join Date
    01-27-2011
    Location
    Rochester, NY
    MS-Off Ver
    Excel 2007
    Posts
    19

    Counting Unique combinations of two variables

    Good Morning. I'm working on a data set that lists medical procedure codes priced by different vendors. I want to do my analysis only on procedure codes that each of the vendors has provided pricing information for and have it ignore duplicates. For instance, if the same vendor listed the same procedure code and price twice, it only counts unique instances. My goal, is to have a column that indicates how many unique combinations of code and vendor there are in the data set, so I can sort on those to be the only ones I analyze. I've attached a file as an example with the highlighted column the results I'm trying to produce. For instance, Vendors A, B & C each price CPT code 200 at least once, Vendor A prices it twice, but I want the formula to only return 3 for # of unique combinations which tells me each vendor priced this code and therefore I will include it in my analysis.

    Hopefully I've provided enough information for someone to help me, I've wasted far too much time on this. Thanks in advance for your help!!!
    Attached Files Attached Files

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Counting Unique combinations of two variables

    Try:

    =COUNT(1/FREQUENCY(IF($A$2:$A$10=A2,IF($B$2:$B$10<>"",MATCH($B$2:$B$10,$B$2:$B$10,0))),ROW($B$2:$B$10)-ROW($B$2)+1))

    confirmed with CTRL+SHIFT+ENTER and not just ENTER, then copied down.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    01-27-2011
    Location
    Rochester, NY
    MS-Off Ver
    Excel 2007
    Posts
    19

    Re: Counting Unique combinations of two variables

    NBVC, thanks so much! The formula worked great on the first few I tried it on, though it did crash my Excel when I dragged it down the whole data set (30K+ rows). Thanks again!

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Counting Unique combinations of two variables

    If you want to use your helper column C, you can try:

    =SUMPRODUCT((LEFT($C$2:$C$10,3)=A2&"")/COUNTIF($C$2:$C$10,$C$2:$C$10&""))

    copied down... it might be faster....

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1