+ Reply to Thread
Results 1 to 4 of 4

Simplifying a Sumproduct formula

  1. #1
    Registered User
    Join Date
    02-05-2010
    Location
    Bedfordshire, UK
    MS-Off Ver
    Excel 2003
    Posts
    8

    Simplifying a Sumproduct formula

    I'm using Excel 2003. I have been using SUMPRODUCT to look at too compare columns and data that is contained in both.

    Column L11:L52 contains the numbers 1 to 4 and Column K11:K52 contains the word YES in some cells. I just want to look and see if text is contained in a row in column L is it contained in that row in column K. This is the formula I'm using but it seems over complicated and I'm sure there is a way of just looking if the cell contains information without worrying what it is.

    =SUMPRODUCT(--(Data!$L$11:$L$52=1),--(Data!$K$11:$K$52="YES"))+SUMPRODUCT(--(Data!$L$11:$L$52=2),--(Data!$K$11:$K$52="YES"))+SUMPRODUCT(--(Data!$L$11:$L$52=3),--(Data!$K$11:$K$52="YES"))+SUMPRODUCT(--(Data!$L$11:$L$52=4),--(Data!$K$11:$K$52="YES"))

    Any help gratefully recieved, I'm something of an amateur at this.
    Last edited by BobTheRockeer; 02-08-2010 at 09:50 AM.

  2. #2
    Valued Forum Contributor rwgrietveld's Avatar
    Join Date
    09-02-2008
    Location
    Netherlands
    MS-Off Ver
    XL 2007 / XL 2010
    Posts
    1,671

    Re: Simplifying a Sumproduct formula

    This Array function would work
    Please Login or Register  to view this content.
    Press Ctrl+Shift+Enter

    Alternative
    Please Login or Register  to view this content.
    Looking for great solutions but hate waiting?
    Seach this Forum through Google

    www.Google.com
    (e.g. +multiple +IF site:excelforum.com/excel-general/ )

    www.Google.com
    (e.g. +fill +combobox site:excelforum.com/excel-programming/ )

    Ave,
    Ricardo

  3. #3
    Registered User
    Join Date
    02-05-2010
    Location
    Bedfordshire, UK
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Simplifying a Sumproduct formula

    =SUM(--(K11:K52<>"")*(L11:L52<>""))

    The array formula above fixed it but could not get the other to work.

    Thank you very much!

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Simplifying a Sumproduct formula

    You can of course still use SUMPRODUCT if you prefer ?

    =SUMPRODUCT(--ISNUMBER($L$11:$L$52),--($K$11:$K$52="Yes"))

    or if you wish to restrict to just 1 to 4

    =SUMPRODUCT(--ISNUMBER(MATCH($L$11:$L$52,{1,2,3,4},0)),--($K$11:$K$52="Yes"))

    If you want to avoid SUMPRODUCT and Arrays altogether simply use concatenation in another column, eg:

    M11: =L11&"@"&K11
    copied down

    Then

    =SUM(COUNTIF($M$11:$M$52,{1,2,3,4}&"@Yes"))

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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