Results 1 to 5 of 5

Thread: Sum of Alternate Columns

  1. #1
    Member
    Join Date
    Jun 2012
    Posts
    80
    Rep Power
    12

    Sum of Alternate Columns

    Hi Guys,

    I would like to know a formula to add up alternate columns in excel.
    I have attached the sample of the file I will be using.

    Please note:
    1) i need the totals of "Successful" columns in column J.
    2) I need the totals of "Total" columns in column K.
    3) I will need a self updating formula or something which wont need me to change the formula as and when i add columns after Column I. As this is a daily updated sheet, I will add two columns everyday and so the totals should updated automatically.

    Please help.

    Sample.xls

  2. #2
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    Hi

    In J3

    =SUMIF($D$2:I$2,"Successful",$D3:I3)

    In K3

    =SUMIF($D$2:J$2,"Total",$D3:J3)

    I would suggest you to bring the Successful Total and Overall Total columns into Col D & E, so that the formula can be made dynamic.

    In that case the formula would be

    =SUMIF($F$2:AA$2,"Successful",$F3:AA3)

    =SUMIF($F$2:AA$2,"Total",$F3:AA3)

    Replace the highlighted AA with appropriate end column reference.
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  3. #3
    Senior Member LalitPandey87's Avatar
    Join Date
    Sep 2011
    Posts
    222
    Rep Power
    13
    Hi

    In J3 with Ctrl + Shift + Enter

    =SUMIF(OFFSET($D$2,0,0,1,MAX(IF($D$2:$IV$2 = $D$2, COLUMN($D$2:$IV$2 ),0))-2),$D$2,OFFSET($D$2,ROWS($J$3:$J3),0,1,MAX(IF($D$2 :$IV$2 = $D$2, COLUMN($D$2:$IV$2 ),0))-2))

    In K3 with Ctrl + Shift + Enter

    =SUMIF(OFFSET($D$2,0,0,1,MAX(IF($D$2:$IV$2 = $E$2, COLUMN($D$2:$IV$2 ),0))-2),$E$2,OFFSET($D$2,ROWS($K$3:$K3),0,1,MAX(IF($D$2 :$IV$2 = $E$2, COLUMN($D$2:$IV$2 ),0))-2))

    Tried with inserting new column in between and its working.



  4. #4
    Member
    Join Date
    Jun 2012
    Posts
    80
    Rep Power
    12
    Worked like a charm! Thank you

    Quote Originally Posted by LalitPandey87 View Post
    Hi

    In J3 with Ctrl + Shift + Enter

    =SUMIF(OFFSET($D$2,0,0,1,MAX(IF($D$2:$IV$2 = $D$2, COLUMN($D$2:$IV$2 ),0))-2),$D$2,OFFSET($D$2,ROWS($J$3:$J3),0,1,MAX(IF($D$2 :$IV$2 = $D$2, COLUMN($D$2:$IV$2 ),0))-2))

    In K3 with Ctrl + Shift + Enter

    =SUMIF(OFFSET($D$2,0,0,1,MAX(IF($D$2:$IV$2 = $E$2, COLUMN($D$2:$IV$2 ),0))-2),$E$2,OFFSET($D$2,ROWS($K$3:$K3),0,1,MAX(IF($D$2 :$IV$2 = $E$2, COLUMN($D$2:$IV$2 ),0))-2))

    Tried with inserting new column in between and its working.



  5. #5
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,122
    Rep Power
    10
    You may also try these non array fomulas as well.

    In J3

    =SUMIF($D$2:INDEX($D$2:IV$2,LastCol-2),"Successful",$D3:INDEX($D3:IV3,LastCol))

    In K3

    =SUMIF($D$2:INDEX($D$2:IV$2,LastCol-2),"Total",$D3:INDEX($D3:IV3,LastCol))

    Hit Ctrl+F3 and define LastCol : =MATCH("zzzzzz",Sheet1!$D$1:$IV$1)
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

Similar Threads

  1. Replies: 4
    Last Post: 08-20-2013, 06:28 PM
  2. Replies: 3
    Last Post: 05-23-2013, 11:17 PM
  3. The Sum of A1 + A2 + A3 + A4 = 52
    By stanleydgromjr in forum Excel Help
    Replies: 3
    Last Post: 08-09-2011, 07:33 AM

Posting Permissions

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