+ Reply to Thread
Results 1 to 11 of 11

Stop counting the blanks in formula

  1. #1
    Registered User
    Join Date
    06-25-2013
    Location
    USA
    MS-Off Ver
    Excel 2003
    Posts
    44

    Stop counting the blanks in formula

    Hi All,

    In the attached file (tournament file) I have all my formula's pulling information from the Master Schedule. It all seems to work, but one little issue. The Tie Column keeps counting blank ("") as ties instead of ignoring them. It is only on this column and I am sure it is because of the formula I am using. I have tried a couple different variations, even adding a new if statement, but it doesn't seem to work.

    In the data, it should only show Edgewood and Vipers as a tie. It should view the blanks (games with no scores) as games unplayed. Example: Fishers Tigers Red should only show as 1 game played.

    The formula I used works well for tallying wins and losses and not counting blanks, it seems to be the ties it struggles with.

    Here is the formula I am using now below.

    =(SUMPRODUCT(('Master Schedule'!$A$3:$A$109='Teams Entered'!$B2)*('Master Schedule'!$B$3:$B$109='Master Schedule'!$E$3:$E$109)))+(SUMPRODUCT(('Master Schedule'!$D$3:$D$109='Teams Entered'!$B2)*('Master Schedule'!$E$3:$E$109='Master Schedule'!$B$3:$B$109))))
    Attached Files Attached Files

  2. #2
    Forum Guru :) Sixthsense :)'s Avatar
    Join Date
    01-01-2012
    Location
    India>Tamilnadu>Chennai
    MS-Off Ver
    2003 To 2010
    Posts
    12,770

    Re: Stop counting the blanks in formula

    I am really confused and unable to understand what you are trying to do in this line....

    ('Master Schedule'!$B$3:$B$109='Master Schedule'!$E$3:$E$109)


    If your problem is solved, then please mark the thread as SOLVED>>Above your first post>>Thread Tools>>
    Mark your thread as Solved


    If the suggestion helps you, then Click *below to Add Reputation

  3. #3
    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,939

    Re: Stop counting the blanks in formula

    change your ARRAY formula to this...
    =IF($B2="","",(SUMPRODUCT(('Master Schedule'!$A$3:$A$109=$B2)*('Master Schedule'!$B$3:$B$109='Master Schedule'!$E$3:$E$109)*('Master Schedule'!$B$3:$B$109<>"")))+(SUMPRODUCT(('Master Schedule'!$D$3:$D$109=$B2)*('Master Schedule'!$E$3:$E$109='Master Schedule'!$B$3:$B$109)*('Master Schedule'!$E$3:$E$109<>""))))

    (added a test for <>"" for B and E)

    @ Six, that is testing for the same score (a tie/draw) in B and E
    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

  4. #4
    Forum Guru :) Sixthsense :)'s Avatar
    Join Date
    01-01-2012
    Location
    India>Tamilnadu>Chennai
    MS-Off Ver
    2003 To 2010
    Posts
    12,770

    Re: Stop counting the blanks in formula

    Thanks for the confirmation FDibbins

  5. #5
    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,939

    Re: Stop counting the blanks in formula

    well, thats my understanding, anyway

  6. #6
    Forum Guru :) Sixthsense :)'s Avatar
    Join Date
    01-01-2012
    Location
    India>Tamilnadu>Chennai
    MS-Off Ver
    2003 To 2010
    Posts
    12,770

    Re: Stop counting the blanks in formula

    Lets hope it covers the OP's requirement

  7. #7
    Registered User
    Join Date
    06-25-2013
    Location
    USA
    MS-Off Ver
    Excel 2003
    Posts
    44

    Re: Stop counting the blanks in formula

    Hello,

    You are correct FDibbins. That is supposed to be looking to see if the scores are tie/draw.

    As to your formula, that was spot on. I knew I was missing something simple. I kept trying to do If and countif and such. Sometimes after staring at things to long your mind just stops processing properly. Thank you again.

  8. #8
    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,939

    Re: Stop counting the blanks in formula

    yes, sometimes you stare so hard, you cant see whats in front of you lol

    Happy to help and thanks for the feedback

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

    Re: Stop counting the blanks in formula

    You could use a single SUMPRODUCT, e.g. this formula should get the same result:

    =IF($B2="","",SUMPRODUCT(('Master Schedule'!$A$3:$D$109=$B2)*('Master Schedule'!$B$3:$B$109='Master Schedule'!$E$3:$E$109)*('Master Schedule'!$B$3:$B$109<>"")))

    Note: as with most SUMPRODUCT formulas you don't need CTRL+SHIFT+ENTER with this formula
    Last edited by daddylonglegs; 12-05-2013 at 12:40 PM.
    Audere est facere

  10. #10
    Registered User
    Join Date
    06-25-2013
    Location
    USA
    MS-Off Ver
    Excel 2003
    Posts
    44

    Re: Stop counting the blanks in formula

    Hi Daddylonglegs,

    This formula also works and it would simplify my formula even further. I can even apply this to some of the other columns. When I built them, I was doing 1 piece at a time. Thanks for this tip. I always like to have the simplest formula possible if I can get there.

    Again, this forum has been incredibly helpful for both my play and work projects.

  11. #11
    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,939

    Re: Stop counting the blanks in formula

    Thanks DDL, I wasnt even thinking about simplifying it, just about adding the extra criteria

+ 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. Formula to stop the counting based on date
    By joseph_yap22 in forum Excel Formulas & Functions
    Replies: 27
    Last Post: 08-20-2013, 07:58 AM
  2. Stop a counting formula
    By pattaz in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 08-09-2013, 06:06 AM
  3. Stop formula counting when it is equal to another cell?
    By Margate in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 06-08-2013, 08:04 PM
  4. =sum formula not counting blanks.
    By Kuzman15 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 05-31-2013, 06:05 PM
  5. sum product counting blanks, how can i stop it!
    By xenohadden in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 08-13-2012, 09:18 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