+ Reply to Thread
Results 1 to 5 of 5

count with multiple criteria without duplicates based on a different column

  1. #1
    Registered User
    Join Date
    10-22-2012
    Location
    DR-Congo
    MS-Off Ver
    Excel 2007
    Posts
    6

    count with multiple criteria without duplicates based on a different column

    Hi,

    following the discussion from
    http://www.excelforum.com/excel-form...ml#post3434799

    i have the following question;

    I've tried to use the formula introduced by Daddylonglegs but it's not working for me. my case is slightly different. the formula i need, based on Daddy's formula is below. it doesn't work but should be something like that i suppose.

    =SUM(IF(FREQUENCY(IF($H$8:$H$2381>AQ2383,IF($H$8:$H$2381<AQ2384,$AD$8:$AD$2381="paid", MATCH($L$7:$L$2381,$L$7:$L$2381,0))),ROW($L$7:$L$2381)-ROW($L$7)+1),1))


    so basically,
    1-I verify that in column H, the date is bigger than AQ2383
    2-same thing as #1, verifying in column H that the date is smaller than AQ2384
    3-then i want from column AD, only "paid" text. (and what do i need to do if i want "paid" and "cancelled"??)
    4-this is where i get stuck, i want the count of unique values in column L.

    i've also tried the formula below with sumproduct and it gives me correct value, but it counts all the duplicates. but with this sumproduct, I don't know how i can have it count the unique values in column L..
    =SUMPRODUCT(($H$8:$H$2381>=D2)*($H$8:$H$2381<=D3)*($AD$8:$AD$2381={"paid","cancelled"}))

    thanks a lot in advance for your support

  2. #2
    Valued Forum Contributor
    Join Date
    03-16-2012
    Location
    Aarhus, Denmark
    MS-Off Ver
    Excel 2007
    Posts
    992

    Re: count with multiple criteria without duplicates based on a different column

    You could probably get a single-formula solution, but how about splitting it in two?

    One for "paid" and one for "cancelled", and then add them?
    Sincerely
    S?ren Larsen

    "Give a man a fish, and you'll feed him for a day. Give a man a fishing rod, and he'll steal your yacht!"

  3. #3
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: count with multiple criteria without duplicates based on a different column

    You are missing an IF in that version (and all ranges should start from the same row), so formula should be this, assuming range starts at row 7

    =SUM(IF(FREQUENCY(IF($H$7:$H$2381>AQ2383,IF($H$7:$H$2381<AQ2384,IF($AD$7:$AD$2381="paid", MATCH($L$7:$L$2381,$L$7:$L$2381,0)))),ROW($L$7:$L$2381)-ROW($L$7)+1),1))

    ....although you will get an error if any of L7:L2381 are blank so normally you use an extra IF to filter out those rows, like this

    =SUM(IF(FREQUENCY(IF($H$7:$H$2381>AQ2383,IF($H$7:$H$2381<AQ2384,IF($AD$7:$AD$2381="paid", IF($L$7:$L$2381<>"",MATCH($L$7:$L$2381,$L$7:$L$2381,0))))),ROW($L$7:$L$2381)-ROW($L$7)+1),1))

    and consider "paid" or "cancelled" with this version

    =SUM(IF(FREQUENCY(IF($H$7:$H$2381>AQ2383,IF($H$7:$H$2381<AQ2384,IF($AD$7:$AD$2381={"paid","cancelled"}, IF($L$7:$L$2381<>"",MATCH($L$7:$L$2381,$L$7:$L$2381,0))))),ROW($L$7:$L$2381)-ROW($L$7)+1),1))

    all formulas need to be confirmed with CTRL+SHIFT+ENTER
    Audere est facere

  4. #4
    Registered User
    Join Date
    10-22-2012
    Location
    DR-Congo
    MS-Off Ver
    Excel 2007
    Posts
    6

    Re: count with multiple criteria without duplicates based on a different column

    wow! thank you Daddylonglegs! it works like a charm!!

    i owe you one!

  5. #5
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: count with multiple criteria without duplicates based on a different column

    Based on your last post in this thread, its apparent that you are satisfied with the solution(s) you've received and have solved your question, but you haven't marked your thread as "SOLVED". I will do it for you this time.

    In future, to mark your thread as Solved, you can do the following -
    Select Thread Tools-> Mark thread as Solved.

    Incase your issue is not solved, you can undo it as follows -
    Select Thread Tools-> Mark thread as Unsolved.

    Also, since you are relatively new to the forum, i would like to inform you that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post which helped you. This adds to the reputation of the person who has taken the time to help you.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. How to count cells that meet multiple criteria, leaving out duplicates
    By jsgray in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 10-11-2013, 07:26 AM
  2. Replies: 3
    Last Post: 05-23-2013, 07:50 PM
  3. [SOLVED] Count without duplicates based on multiple criteria from different cells
    By perryadam in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 04-23-2013, 12:54 PM
  4. [SOLVED] Deleting Duplicates Based on Multiple Criteria from Multiple Columns
    By Franklic in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-09-2012, 05:31 PM
  5. Count first entries (ignore duplicates) against multiple criteria
    By Bazza in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 04-28-2008, 11:44 AM

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