Results 1 to 11 of 11
  1. #1
    3 Star Lounger
    Join Date
    May 2003
    Location
    Mid-Cheshire, England
    Posts
    275
    Thanks
    1
    Thanked 2 Times in 2 Posts

    Sum alternate cells (Excel 2000 SP3)

    Is there a convenient way to tell Excel to sum alternate cells in either rows or columns? I have 80 columns with text then a number in adjacent cells repeated 40 times in each row. I can type =SUM(B2+D2+F2+H2+J2+ . . . . . . . . +BB2 etc ) but I thought there should be a more elegant way of writing the formula.

    Thank you in anticipation of assistance in this question.

  2. Subscribe to our Windows Secrets Newsletter - It's Free!

    Get our unique weekly Newsletter with tips and techniques, how to's and critical updates on Windows 7, Windows 8, Windows XP, Firefox, Internet Explorer, Google, etc. Join our 480,000 subscribers!

    Excel 2013: The Missing Manual

    + Get this BONUS — free!

    Get the most of Excel! Learn about new features, basics of creating a new spreadsheet and using the infamous Ribbon in the first chapter of Excel 2013: The Missing Manual - Subscribe and download Chapter 1 for free!

  3. #2
    5 Star Lounger
    Join Date
    Jan 2001
    Location
    La Jolla,CA
    Posts
    1,040
    Thanks
    11
    Thanked 35 Times in 34 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    Since SUM ignores text (treats it as a zero), try: =SUM(B2:CB2)

  4. #3
    3 Star Lounger
    Join Date
    Jan 2002
    Location
    The Hague, Netherlands
    Posts
    283
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    =SUMPRODUCT(--(MOD(COLUMN(B2:BB2)-COLUMN(B2)+0,2)=0),B2:BB2)
    Microsoft MVP - Excel

  5. #4
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 15 Times in 15 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    If the values in A2, C2, etc. are really text, use kweaver's formula. If there may be numbers among them:
    <code>
    =SUMPRODUCT(A2:BB2,1-MOD(COLUMN(A2:BB2),2))</code>

  6. #5
    Platinum Lounger
    Join Date
    Feb 2002
    Location
    A Magic Forest in Deepest, Darkest Kent
    Posts
    5,681
    Thanks
    0
    Thanked 1 Time in 1 Post

    Re: Sum alternate cells (Excel 2000 SP3)

    Hi malcolm

    Have you tried these forulas

    To sum every other row:

    =SUMPRODUCT(MOD(ROW(A1:A100),2)*A1:A100) (odd rows)

    =SUMPRODUCT((1-MOD(ROW(A1:A100),2))*A1:A100) (even rows)

    To sum every other column:

    =SUMPRODUCT(MOD(COLUMN(A1:Z1),2)*A1:Z1) (odd columns)

    =SUMPRODUCT((1-MOD(COLUMN(A1:Z1),2))*A1:Z1) (even columns)


    Obviously change the range to suit your needs
    Jerry

  7. #6
    3 Star Lounger
    Join Date
    May 2003
    Location
    Mid-Cheshire, England
    Posts
    275
    Thanks
    1
    Thanked 2 Times in 2 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    Hans - I appreciate very highly your response as well as the others I hope they see this response from me.

    Malcolm

  8. #7
    3 Star Lounger
    Join Date
    May 2003
    Location
    Mid-Cheshire, England
    Posts
    275
    Thanks
    1
    Thanked 2 Times in 2 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    >If the values in A2, C2, etc. are really text, use kweaver's formula. If there may be numbers among them:

    =SUMPRODUCT(A2:BB2,1-MOD(COLUMN(A2:BB2),2))

    As there are numbers in the `text' cells I have used the above formula in the form:

    =SUMPRODUCT(H4:BA4,1-MOD(COLUMN(H4:BA4),2))

    When I enter a number in I4 and press Enter the formula that is in E4 it does not respond; it continues to diplay 0 (zero). Can you see an error in the way I have used your formula?

  9. #8
    Platinum Lounger
    Join Date
    Feb 2002
    Location
    A Magic Forest in Deepest, Darkest Kent
    Posts
    5,681
    Thanks
    0
    Thanked 1 Time in 1 Post

    Re: Sum alternate cells (Excel 2000 SP3)

    Hi Malcolm

    I think you will need to convert the text to an integer. A nice and quick trick is to:

    1) Type 1 into a blank cell
    2) Highlight the cell
    3) Edit-->Copy
    4) Highlight calls H4 to BA4
    5) Goto the edit menu select Paste Special
    6) Select Multiply
    7) Press OK

    This will convert any numbers stored as text in the range to a number. I believe this should solve your problem.
    Jerry

  10. #9
    3 Star Lounger
    Join Date
    May 2003
    Location
    Mid-Cheshire, England
    Posts
    275
    Thanks
    1
    Thanked 2 Times in 2 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    Jerry,

    This is my original question:

    Is there a convenient way to tell Excel to sum alternate cells in either rows or columns? I have 80 columns with text then a number in adjacent cells repeated 40 times in each row. I can type =SUM(B2+D2+F2+H2+J2+ . . . . . . . . +BB2 etc ) but I thought there should be a more elegant way of writing the formula.

    In cell H4, J4, L4 etc etc through to AZ4 there can be text & as it has turned out since numbers also. I want the formula to ignore H4, J4, L4 etc etc through to AZ4. I want the formula to sum the numbers in I4, K4, M4 etc etc to BA4. that is every second cell in row 4.

    Can you help me with that aim please?

  11. #10
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 15 Times in 15 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    You originally stated that you wanted to add the even-numbered columns B, D, F, etc.
    Column I is an odd-numbered column (it is the 9th column), so a number in I4 will not be included in the result of the formula - according to your specification!
    If you want to add the odd-numbered columns, change the formula to
    <code>
    =SUMPRODUCT(H4:BA4,MOD(COLUMN(H4:BA4),2))</code>

  12. #11
    3 Star Lounger
    Join Date
    May 2003
    Location
    Mid-Cheshire, England
    Posts
    275
    Thanks
    1
    Thanked 2 Times in 2 Posts

    Re: Sum alternate cells (Excel 2000 SP3)

    Thank you for putting me right. It is very much appreciated.

Posting Permissions

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