+ Reply to Thread
Results 1 to 8 of 8

Calculating two values of cells but displaying in numbers

Hybrid View

  1. #1
    Forum Contributor
    Join Date
    01-02-2015
    Location
    Kuala Lumpur, Malaysia
    MS-Off Ver
    2007
    Posts
    272

    Calculating two values of cells but displaying in numbers

    Hi All,

    Hope someone can help me. Attached is a sample excel file.

    Mapping Calc.xlsx

    Im having a difficulty in getting the value from sheet 2 column B because it contains spaces and it cant count the value of more than one field unit.
    I tried using the below code but it does not grab the value because of spaces.

    =SUMPRODUCT(('Sheet2'!B:B="DS")*('Sheet2'!A:A="successful")

    Hope someone can either correct my formula in sheet 2 and sheet 1. :-)

    Kind Regards,
    Mark.

  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: Calculating two values of cells but displaying in numbers

    In C4 cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Successful")*(TRIM(Sheet1!$B$1:$B$50)=B4))

    Drag the above formula upto C14 Cell



    In C15 cell

    =SUMPRODUCT((Sheet1!$A12:$A$50="Successful")*(LEN(TRIM(Sheet1!$B$12:$B$50))=0))



    In C16 Cell

    =COUNTIFS(Sheet1!$A$1:$A$50,"Successful",Sheet1!$B$1:$B$50,"*DS*",Sheet1!$B$1:$B$50,"*TR*",Sheet1!$B$1:$B$50,"*GF*")


    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
    Forum Contributor
    Join Date
    01-02-2015
    Location
    Kuala Lumpur, Malaysia
    MS-Off Ver
    2007
    Posts
    272

    Re: Calculating two values of cells but displaying in numbers

    Quote Originally Posted by :) Sixthsense :) View Post
    In C4 cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Successful")*(TRIM(Sheet1!$B$1:$B$50)=B4))

    Drag the above formula upto C14 Cell



    In C15 cell

    =SUMPRODUCT((Sheet1!$A12:$A$50="Successful")*(LEN(TRIM(Sheet1!$B$12:$B$50))=0))



    In C16 Cell

    =COUNTIFS(Sheet1!$A$1:$A$50,"Successful",Sheet1!$B$1:$B$50,"*DS*",Sheet1!$B$1:$B$50,"*TR*",Sheet1!$B$1:$B$50,"*GF*")
    Hi SixthSense,

    Yes it works for column C4-C15 but C16 still does not work. Maybe I explained wrong. I need C6 to show in numbers how many fields in Sheet1 which has more than 1 field type instead of just DS TR and GF. Also do you have any formula to calculate for column D4 to D16 if I need the total of both successful and not successful? Sorry to add on more.

    Kind Regards,
    Mark.

  4. #4
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,915

    Re: Calculating two values of cells but displaying in numbers

    D4=IF(B4="N/A",SUMPRODUCT(1*(TRIM(Sheet1!$B$2:$B$50)="")),IF(B4="Multiple Fields",SUMPRODUCT(1*ISNUMBER(SEARCH(" ",TRIM(Sheet1!$B$2:$B$50)))),SUMPRODUCT(1*ISNUMBER(SEARCH($B4,TRIM(Sheet1!$B$2:$B$50))))))
    Samba

    Say thanks to those who have helped you by clicking Add Reputation star.

  5. #5
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,915

    Re: Calculating two values of cells but displaying in numbers

    C4=IF(B4="N/A",SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*(TRIM(Sheet1!$B$2:$B$50)="")),IF(B4="Multiple Fields",SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*ISNUMBER(SEARCH(" ",TRIM(Sheet1!$B$2:$B$50)))),SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*ISNUMBER(SEARCH($B4,TRIM(Sheet1!$B$2:$B$50))))))
    Try this and copy towards down

  6. #6
    Forum Contributor
    Join Date
    01-02-2015
    Location
    Kuala Lumpur, Malaysia
    MS-Off Ver
    2007
    Posts
    272

    Re: Calculating two values of cells but displaying in numbers

    Quote Originally Posted by nflsales View Post
    C4=IF(B4="N/A",SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*(TRIM(Sheet1!$B$2:$B$50)="")),IF(B4="Multiple Fields",SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*ISNUMBER(SEARCH(" ",TRIM(Sheet1!$B$2:$B$50)))),SUMPRODUCT((Sheet1!$A$2:$A$50="Successful")*ISNUMBER(SEARCH($B4,TRIM(Sheet1!$B$2:$B$50))))))
    Try this and copy towards down
    Hi Siva,

    Unfortunately it doesnt work that way because I need the total in Sheet2 to be the exact number of rows in Sheet1. To be exact Sheet1 has 49 rows which means Sheet2 should have a total of 49 as well. The formula you provided calculates more than once for each cell. The one I need is for column C4-C15 must only contain data from Sheet1 Column B is there is only one value there. The ones with more than one value should be in Multiple Fields. :-)

    Kind Regards,
    Mark.

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

    Re: Calculating two values of cells but displaying in numbers

    Revised C16 Cell formula

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Successful")*(LEN(TRIM(Sheet1!$B$1:$B$50))<>LEN(SUBSTITUTE(TRIM(Sheet1!$B$1:$B$50)," ",""))))


    In D4 Cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Not Successful")*(TRIM(Sheet1!$B$1:$B$50)=$B4))+C4

    Drag the above formula upto D14 Cell


    In D15 Cell

    =SUMPRODUCT((Sheet1!$A12:$A$50="Not Successful")*(LEN(TRIM(Sheet1!$B$12:$B$50))=0))+C15


    In D16 Cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Not Successful")*(LEN(TRIM(Sheet1!$B$1:$B$50))<>LEN(SUBSTITUTE(TRIM(Sheet1!$B$1:$B$50)," ",""))))+C16

    Refer the attached file
    Attached Files Attached Files

  8. #8
    Forum Contributor
    Join Date
    01-02-2015
    Location
    Kuala Lumpur, Malaysia
    MS-Off Ver
    2007
    Posts
    272

    Re: Calculating two values of cells but displaying in numbers

    Quote Originally Posted by :) Sixthsense :) View Post
    Revised C16 Cell formula

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Successful")*(LEN(TRIM(Sheet1!$B$1:$B$50))<>LEN(SUBSTITUTE(TRIM(Sheet1!$B$1:$B$50)," ",""))))


    In D4 Cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Not Successful")*(TRIM(Sheet1!$B$1:$B$50)=$B4))+C4

    Drag the above formula upto D14 Cell


    In D15 Cell

    =SUMPRODUCT((Sheet1!$A12:$A$50="Not Successful")*(LEN(TRIM(Sheet1!$B$12:$B$50))=0))+C15


    In D16 Cell

    =SUMPRODUCT((Sheet1!$A$1:$A$50="Not Successful")*(LEN(TRIM(Sheet1!$B$1:$B$50))<>LEN(SUBSTITUTE(TRIM(Sheet1!$B$1:$B$50)," ",""))))+C16

    Refer the attached file
    Hi SixthSense,

    This one works perfectly. Thank you very much to you and Siva for helping me out.

    Kind Regards,
    Mark.

+ 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] calculating cells and displaying in user form
    By Juli in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 03-29-2012, 01:43 PM
  2. Displaying negative values in a cell but calculating these as 0
    By janschepens in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 09-05-2011, 08:02 AM
  3. Replies: 7
    Last Post: 06-21-2011, 03:24 AM
  4. Excel chart. Displaying y axis numbers different to actual plot values.
    By Richard Buttrey in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 04-12-2011, 12:40 PM
  5. Displaying the progress of calculating cells
    By MegaWatt in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 05-25-2006, 12:10 PM

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