+ Reply to Thread
Results 1 to 6 of 6

Countif with 2 columns 1 criteria and no duplication

  1. #1
    Registered User
    Join Date
    12-07-2020
    Location
    Europe
    MS-Off Ver
    10
    Posts
    3

    Countif with 2 columns 1 criteria and no duplication

    Hi everyone,
    I spent a lot of time trying to find the correct formula I needed but didn't find anything.

    I want a formula to find how many countries has RED as colour while excluding repetition of countries. So the formula needs to count the number of countries in the column "country" that has RED in the column "colour" all while excluding the repetitions in column "country"

    For example below it would be 3 countries : Mexico (twice but I want it counted as 1) India and China

    Can anyone help ?
    Thank you
    J.


    Country---Colour


    Mexico---Red
    Benin---Orange
    Canada---Blue
    Mexico---Green
    India ---Red
    Mexico---Red
    China---Red

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,725

    Re: Countif with 2 columns 1 criteria and no duplication

    Try this:

    =SUMPRODUCT((1/(COUNTIF($C$4:$C$11,$C$4:$C$11))*($D$4:$D$11="Red")))

    where the C range contains countries and the D range contains colours.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    12-07-2020
    Location
    Europe
    MS-Off Ver
    10
    Posts
    3

    Re: Countif with 2 columns 1 criteria and no duplication

    Hi, thank you for your quick feedback. I tried it but excel tells me that there is an error in the formula. I tried to replace the , with ; it gives a totally wrong number

  4. #4
    Registered User
    Join Date
    12-07-2020
    Location
    Europe
    MS-Off Ver
    10
    Posts
    3

    Re: Countif with 2 columns 1 criteria and no duplication

    There are 17 Red and 11 countries (if I count each country only once) but it gives me 9.333333

  5. #5
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,548

    Re: Countif with 2 columns 1 criteria and no duplication

    Hello J2424 and Welcome to Excel Forum.
    This proposal employs a helper column (C) based on the word Country being in cell A1 and the first instance of Mexico being in cell A3.
    The formula for C3 is: =AND(COUNTIFS(A$3:A3,A3)=1,B3="red")
    After pasting the formula into cell C3 drag the fill handle down to cell C9.
    Note that the helper column could be moved and/or hidden for aesthetic purposes.
    The formula to count distinct entries is: =COUNTIFS(C3:C9,TRUE)
    Let us know if you have any questions.
    Consider taking the time to add to the reputation of everybody that has taken the time to respond to your query.

  6. #6
    Forum Expert
    Join Date
    09-25-2015
    Location
    Milan Italy
    MS-Off Ver
    office 365
    Posts
    1,781

    Re: Countif with 2 columns 1 criteria and no duplication

    A
    B
    C
    D
    E
    1
    Mexico Red count
    2
    Benin Orange
    3
    3
    Canada Blue
    4
    Mexico Green
    5
    India Red
    6
    Mexico Red
    7
    China Red












    E2=SUM(IF(FREQUENCY(IF($B$1:$B$1000="red",MATCH(A1:A1000,A1:A100,0)),ROW($A$1:$A$1000)-ROW(A1)+1),1))


    Control+shift+enter
    Last edited by CARACALLA; 12-10-2020 at 03:02 PM.

+ 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] COUNTIF involving criteria from 2 different columns?
    By FlareChan in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 12-22-2020, 01:35 AM
  2. Replies: 2
    Last Post: 04-09-2014, 03:05 PM
  3. Trying to countif 2 columns meet different criteria
    By ediancoc in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 10-07-2013, 03:37 PM
  4. CountIf Multiple criteria and columns
    By extko1 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 06-05-2013, 12:35 PM
  5. Countif with criteria in multiple columns
    By syoung236 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 08-03-2012, 05:10 PM
  6. Replies: 8
    Last Post: 02-10-2009, 08:56 AM
  7. Countif - Two Criteria in two columns are met.
    By samprince in forum Excel General
    Replies: 12
    Last Post: 06-28-2006, 11:58 AM

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