+ Reply to Thread
Results 1 to 8 of 8

Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

  1. #1
    Registered User
    Join Date
    01-19-2017
    Location
    Minnesota
    MS-Off Ver
    1611
    Posts
    7

    Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Struggling to figure out accurate formulas to return the results I'm looking for. I have attached a spreadsheet for review.

    I want this data to provide three values in G4, H4, & I4:

    1) The total # of DA's in column C... I'm using: =COUNTIF(C:C,"DA")

    2) The total # of occurrences of exactly 1 Service Type "DA" and 1 Service Type "THER NOTE" for the same Client (summing all occurences into one cell).

    3) The total # of occurrences of exactly 1 Service Type "DA" and 2 or more Service Type "THER NOTE's" for the same Client (summing all occurrences into one cell).

    The result should be:

    1) 5

    2) 2

    3) 2
    Attachment 589984
    Attached Images Attached Images
    Last edited by boren0023; 09-12-2018 at 12:57 PM.

  2. #2
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,942

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    You need to use a column of helper formulas. In F2, enter the formula

    =IF(C2="DA",COUNTIFS(B:B,B2,C:C,"THER NOTE"),0)

    and copy down.

    Then use

    =COUNTIF(F:F,1)
    and
    =COUNTIF(F:F,2)

    to return the counts of interest.

    You may want to change F2 to the formula

    =IF(C2="DA",COUNTIFS(B:B,B2,C:C,"THER NOTE",E:E,E2),0)

    if clients may have been paired with other staff.
    Bernie Deitrick
    Excel MVP 2000-2010

  3. #3
    Forum Expert mrice's Avatar
    Join Date
    06-22-2004
    Location
    Surrey, England
    MS-Off Ver
    Excel 2013
    Posts
    4,967

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    You can do this with the following user defined functions

    Please Login or Register  to view this content.
    Open the VBA editor by hitting Alt F11.
    Insert a new module with Insert - Module
    Paste in the above function
    Go back to the sheet by hitting Alt F11.

    In H4, enter =GetOneDAPlusOneTherNote(B2:B13,C2:C13,E2:E13,"Jones, Tom")

    In I4 enter =GetOneDAPlusManyTherNote(B2:B13,C2:C13,E2:E13,"Jones, Tom")

    Remember to save the workbook as a macro enabled workbook .xlsm
    Martin

  4. #4
    Registered User
    Join Date
    01-19-2017
    Location
    Minnesota
    MS-Off Ver
    1611
    Posts
    7

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Great work Bernie. It appears it is not encompassing an instance where there is a client with 1 DA and more than 2 THER NOTES. Suggestions?
    Last edited by boren0023; 09-12-2018 at 03:52 PM.

  5. #5
    Registered User
    Join Date
    01-19-2017
    Location
    Minnesota
    MS-Off Ver
    1611
    Posts
    7

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Quote Originally Posted by mrice View Post
    You can do this with the following user defined functions

    Please Login or Register  to view this content.
    Open the VBA editor by hitting Alt F11.
    Insert a new module with Insert - Module
    Paste in the above function
    Go back to the sheet by hitting Alt F11.

    In H4, enter =GetOneDAPlusOneTherNote(B2:B13,C2:C13,E2:E13,"Jones, Tom")

    In I4 enter =GetOneDAPlusManyTherNote(B2:B13,C2:C13,E2:E13,"Jones, Tom")

    Remember to save the workbook as a macro enabled workbook .xlsm


    Martin,

    Your VBA macro works wonderfully!!! I sincerely appreciate the time and energy you put into answering my question. Thank you so much!

  6. #6
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,942

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Sorry - missed the "or more" part

    =IF(C2="DA",MIN(2,COUNTIFS(B:B,B2,C:C,"THER NOTE")),0)

  7. #7
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,929

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Your post does not comply with Rule 3 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

    Please make sure to include the full link, so that other members will be permitted to continue helping you

    Note that if you have fewer than 10 posts, you may need to type the link, or past it in pieces (or ask a mod to do that for you)
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  8. #8
    Registered User
    Join Date
    01-19-2017
    Location
    Minnesota
    MS-Off Ver
    1611
    Posts
    7

    Re: Excel COUNTIFS Assistance with Duplicate Values & Multiple Criteria

    Quote Originally Posted by FDibbins View Post
    Your post does not comply with Rule 3 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

    Please make sure to include the full link, so that other members will be permitted to continue helping you

    Note that if you have fewer than 10 posts, you may need to type the link, or past it in pieces (or ask a mod to do that for you)


    Thank you for the information. I attempted to update my original post to include cross-posted links, but you are correct - I received the error due to having less than 10 posts. Should I remove my question on the other forums and/or email the links to you?

+ 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. [SOLVED] Excel Formula with SUM+COUNTIFS and NOT EQUAL TO multiple criteria's
    By mchilapur in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 08-10-2018, 06:28 AM
  2. Multiple COUNTIFS ignoring duplicate values in a column
    By hamzahs in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 02-27-2015, 11:31 AM
  3. [SOLVED] Assistance Needed Identifying Min Values Based On Multiple Criteria
    By elderdane in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 09-25-2014, 05:00 PM
  4. Assistance in Sum/CountA formula to only count 1 of duplicate values
    By Excelhandicap in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 11-21-2013, 09:06 PM
  5. Summing of Multiple Criteria sum but not counting Duplicate Values
    By chadman in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 06-25-2013, 07:34 AM
  6. Need Macro that will pick multiple criteria from duplicate values
    By jonnic14 in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 10-02-2012, 12:11 AM
  7. Replies: 6
    Last Post: 02-07-2012, 08:21 PM

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