Countifs
Page 1 of 2 12 LastLast
Results 1 to 10 of 11

Thread: Countifs

  1. #1
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Countifs

    Having a lot of issues trying to resolve this problem.
    so i currently have 3 league tables. each league table is then automatically changed depending on the options selected from some drop downs.

    1. shows the sales of staff at a particular site. You have an option of new sales, used sales and then overall sales. you can then select the date drop down to change the month, (Jan - Dec and then an option for YTD). you can also select which site you want to show on this by the 3rd drop down.
    2. Shows a league table for sites. again you can change the criteria for this by changing the month or changing the sale type (the site drop down has no affect on this table)
    3. this table is an overall sales table. it shows every member of staff. This again can be changed to show the month and sales type (site drop down has no affect on this table either.


    The issue i am having is with table 1. the table is there and set up. the issue i am having is there is a lot of #NUM ! in the table. this is because after the last person for the site it is bringing back num!s in the table which in turn is messing with the ranking system etc.

    now i was thinking of using a countif formula at the beginning where it would count the amount of people at site, once the row is more than at site then it will start returning blanks and the table would therefore work.

    The problem i have is splitting the new and used sales and counting these. if it was just a simple new/used it wouldnt be bad, but we also have staff that are classed as combined. this means they can sell both new and used.

    so basically i want to create a count if at the beginning of my formula where it is like this

    if new is selected in the drop down count the total number of new and combined staff at the site that is selected.
    If used is selected in the drop down count the total number of used and combined staff at the site that is selected.
    If overall is selected then count all the staff at the site selected.

    any help with this would be fantastic

  2. #2
    MrExcel MVP FormR's Avatar
    Join Date
    Aug 2011
    Location
    UK
    Posts
    6,059
    Post Thanks / Like
    Mentioned
    24 Post(s)
    Tagged
    2 Thread(s)

    Default Re: Countifs

    Quote Originally Posted by jwgreen1986 View Post
    if new is selected in the drop down count the total number of new and combined staff at the site that is selected.
    If used is selected in the drop down count the total number of used and combined staff at the site that is selected.
    If overall is selected then count all the staff at the site selected.
    Hi, something like this maybe?

    Excel 2013/2016
    ABCDEF
    1Sitesale typeSiteSale Typecount
    2AnewAnew2
    3AusedAused4
    4AcombinedAoverall5
    5Bcombined
    6Bcombined
    7Bused
    8Bcombined
    9Aused
    10Aused
    11Bnew

    Sheet1



    Worksheet Formulas
    CellFormula
    F2=COUNTIFS(A:A,D2,B:B,IF(E2="overall","*",E2),B:B,"<>combined")+COUNTIFS(A:A,D2,B:B,"combined")

    [code]your code[/code]

  3. #3
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Countifs

    hi thanks,

    however i dont want it to actually tell me how many sales there has been at the site, i want it to list the people at site. This is the little table i have at the min. the formula i use to drag the name is also below (the rest is a vlookup)

    The issue i have is that i know there are 8 staff that are classed as used at Derby (5 used and 3 combined) but it only brings 5 spots back in the table (im assuming it is only recognising 5 used staff and not including the 3 combined)

    it is similar with the overall tab. when overall is selected i need it to show all the staff at site or bring their names back.

    A B C D E
    Rank Name Site Scheme Sales
    1 W1 Derby Used 7
    2 W2 Derby Combined 5
    3 w3 Derby Used 4
    4 w4 Derby Used 4
    5 w5 Derby Used 2
    6
    7
    8
    9
    10
    Code used to get name
    =IF(ROWS(DA$4:DA4)>(COUNTIFS($D$4:$D$201,Standings!$D$7,$E$4:$E$201,Standings!$D$5)),"",IF(Standings!$D$5="Used",INDEX(Table!$BD$4:$BD$202,SMALL(IF(Standings!$D$7=Table!$BC$4:$BC$202,ROW(Table!$BC$4:$BC$202)-ROW(Table!$DA$4)+1),ROW(1:1))),IF(Standings!$D$5="New",INDEX(Table!$AR$4:$AR$201,SMALL(IF(Standings!$D$7=Table!$AQ$4:$AQ$202,ROW(Table!$AR$4:$AR$202)-ROW(Table!$DA$4)+1),ROW(1:1))),IF(Standings!$D$5="Overall",INDEX(Table!$DH$4:$DH$201,SMALL(IF(Standings!$D$7=Table!$DJ$4:$DJ$202,ROW(Table!$DH$4:$DH$202)-ROW(Table!$DA$4)+1),ROW(1:1))),""))))

    *Edited*
    Standings!D5 in the formula references the drop down to select which scheme you want the table to show (New, Used, Overall)
    Standings!D7 is the drop down for the site.

    i need something to replace $E$4:$E$201,Standings!$D$5 so it will be something like if Standings!$D$5 = Used then countif $E$4:$E$201,"Used" or "Combined"

    if Standings!$D$5 = New then countif $E$4:$E$201,"New" or "Combined"

    if Standings!$D$5 = Overall then countif $E$4:$E$201,"New" or "Combined" or "Used"

    so as it stands the table, when new is selected it will only bring up 6 staff (9 are new in total) it looks like it brings the staff in alphabetically as well from my payroll list.

    when used is selected it will only bring back 5 staff (8 are used in total)

    when overall is selected it is bring none back.

    it is the same with every site. it only brings back the same number it counts for new or used staff at each site and is not including any combined ones.
    Last edited by jwgreen1986; May 21st, 2019 at 08:20 AM.

  4. #4
    MrExcel MVP FormR's Avatar
    Join Date
    Aug 2011
    Location
    UK
    Posts
    6,059
    Post Thanks / Like
    Mentioned
    24 Post(s)
    Tagged
    2 Thread(s)

    Default Re: Countifs

    Quote Originally Posted by jwgreen1986 View Post
    i dont want it to actually tell me how many sales there has been at the site, i want it to list the people at site.
    I think it was all the talk of counting and countifs() that confused

    See if you can adapt this to your set up - for efficiency reason it's better to have the COUNTIFS() function outside of the formula that returns the list.

    Excel 2013/2016
    CDEF
    4Name list
    5Schemeneww4
    6w6
    7SiteDerbyw7
    8
    9Helper3
    10
    11
    12

    Standings



    Worksheet Formulas
    CellFormula
    F5=IF(ROWS(F$5:F5)>$D$9,"",INDEX(table!$B$2:$B$11,SMALL(IF(table!$C$2:$C$11=$D$7,IF(IF($D$5="overall",1,ISNUMBER(MATCH(table!$D$2:$D$11,CHOOSE({1,2},"combined",$D$5),0))),ROW(table!$B$2:$B$11)-MIN(ROW(table!$B$2:$B$11))+1)),ROWS(F$5:F5))))
    D9=COUNTIFS(table!C:C,D7,table!D:D,IF(D5="overall","*",D5),table!D:D,"<>combined")+COUNTIFS(table!C:C,D7,table!D:D,"combined")




    Excel 2013/2016
    ABCDE
    1RankNameSiteSchemeSales
    21W1DerbyUsed7
    32W2DerbyCombined5
    43w3DerbyUsed4
    54w4DerbyUsed4
    65w5DerbyUsed2
    76w6Derbynew
    87w7Derbynew
    98
    109
    1110

    table



    Last edited by FormR; May 21st, 2019 at 10:01 AM.
    [code]your code[/code]

  5. #5
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Countifs

    Hi,

    can you explain the formulas a little more. i understand the helper bit and what you are doing, just not the formula in there. it looks to me like it is just looking at the "Overall" option in the drop down and isnt considering the new or used par of the drop down.

    Quote Originally Posted by FormR View Post
    I think it was all the talk of counting and countifs() that confused

    See if you can adapt this to your set up - for efficiency reason it's better to have the COUNTIFS() function outside of the formula that returns the list.

    Excel 2013/2016
    C D E F
    4 Name list
    5 Scheme new w4
    6 w6
    7 Site Derby w7
    8
    9 Helper 3
    10
    11
    12
    Standings

    Worksheet Formulas
    Cell Formula
    F5 =IF(ROWS(F$5:F5)>$D$9,"",INDEX(table!$B$2:$B$11,SMALL(IF(table!$C$2:$C$11=$D$7,IF(IF($D$5="overall",1,ISNUMBER(MATCH(table!$D$2:$D$11,CHOOSE({1,2},"combined",$D$5),0))),ROW(table!$B$2:$B$11)-MIN(ROW(table!$B$2:$B$11))+1)),ROWS(F$5:F5))))
    D9 =COUNTIFS(table!C:C,D7,table!D:D,IF(D5="overall","*",D5),table!D:D,"<>combined")+COUNTIFS(table!C:C,D7,table!D:D,"combined")




    Excel 2013/2016
    A B C D E
    1 Rank Name Site Scheme Sales
    2 1 W1 Derby Used 7
    3 2 W2 Derby Combined 5
    4 3 w3 Derby Used 4
    5 4 w4 Derby Used 4
    6 5 w5 Derby Used 2
    7 6 w6 Derby new
    8 7 w7 Derby new
    9 8
    10 9
    11 10
    table

  6. #6
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Countifs

    so what i want this table to do is
    when i select New on the drop down from my standings tab (Standings!$D$5) it will list all the staff at the chosen site that are either on the New scheme or combined scheme for the chosen site (Standings!$D$7)

    When i change the drop down to Used i want it to show all the staff that are on the Used scheme or combined scheme for the chosen site (Standings!$D$7)

    When overall is picked i want it to show ever member of staff that work at the chosen site. (Standings!$D$7)

  7. #7
    MrExcel MVP FormR's Avatar
    Join Date
    Aug 2011
    Location
    UK
    Posts
    6,059
    Post Thanks / Like
    Mentioned
    24 Post(s)
    Tagged
    2 Thread(s)

    Default Re: Countifs

    Quote Originally Posted by jwgreen1986 View Post
    so what i want this table to do is
    Try to recreate my example in post 4 and see if it does what you ask - note the formula in F5 in an array formula and need committing with ctrl+shift+enter.
    [code]your code[/code]

  8. #8
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Countifs

    Hi thanks for the reply.
    tried the formula to generate the number. got a #Value error

    =COUNTIFS($D$4:$D$201,Standings!$D$7,Table!$E$4:$E$201,IF(Standings!$D$5="Overall","*",Standings!$D$5),Table!$E$4:$E$20,"<>Combined")+COUNTIFS(Table!$D$4:$D$201,Standings!$D$7,Table!$E$4:$E$201,"Combined")

  9. #9
    MrExcel MVP FormR's Avatar
    Join Date
    Aug 2011
    Location
    UK
    Posts
    6,059
    Post Thanks / Like
    Mentioned
    24 Post(s)
    Tagged
    2 Thread(s)

    Default Re: Countifs

    Quote Originally Posted by jwgreen1986 View Post
    =COUNTIFS($D$4:$D$201,Standings!$D$7,Table!$E$4:$E$201,IF(Standings!$D$5="Overall","*",Standings!$D$5),Table!$E$4:$E$20,"<>Combined")+COUNTIFS(Table!$D$4:$D$201,Standings!$D$7,Table!$E$4:$E$201,"Combined")
    Typo in red?
    Last edited by FormR; May 21st, 2019 at 11:04 AM.
    [code]your code[/code]

  10. #10
    Board Regular
    Join Date
    Mar 2019
    Posts
    63
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Countifs

    Absolutely Fantastic. this is now working fab. brilliant thanks.

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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