Results 1 to 4 of 4
  1. #1
    5 Star Lounger
    Join Date
    Oct 2001
    Location
    San Bernardino, California, USA
    Posts
    734
    Thanks
    0
    Thanked 0 Times in 0 Posts
    I have dates (days) in column B and numbers in column H. I wanted to have column I look at column B and if it is a Friday, to sum the last seven H cells and multiply by 15.

    I thought the following formula would work but it does not... what am I doing wrong please?

    =IF(WEEKDAY(B14)<>6,"",sum("H"&row()-7:H14)*15)

    (This shows the formula in cell I14; so if B14 is a Friday, it should sum H7:H14 then multiply by 15; if B14 is not a Friday, I14 remains blank)

  2. #2
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts
    In I7 (the first row where you could possibly add 7 rows):

    =IF(WEEKDAY(B7)<>6,"",SUM(H1:H7))

    and fill down as far as needed. The B7 and H1:H7 in the formula will automatically be adjusted.

  3. #3
    5 Star Lounger
    Join Date
    Oct 2001
    Location
    San Bernardino, California, USA
    Posts
    734
    Thanks
    0
    Thanked 0 Times in 0 Posts
    Thanks Hans, I did think of that but was hoping there was some way to use the ROW() method. I have seen this used in VBA - especially in loops where something like "M"&row(i) is used. Is this restricted to VBA or can it be used in a formula? Not the row(i) but the Row() plus or minus some number.

    [quote name='HansV' post='785199' date='18-Jul-2009 09:58']In I7 (the first row where you could possibly add 7 rows):

    =IF(WEEKDAY(B7)<>6,"",SUM(H1:H7))

    and fill down as far as needed. The B7 and H1:H7 in the formula will automatically be adjusted.[/quote]

  4. #4
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts
    I don't see the need for that here, but if you wish, you can use the ROW() function in combination with the INDIRECT function.

    For I7:

    =IF(WEEKDAY(B7)<>6,"",SUM(INDIRECT("H"&(ROW()-6)&":H"&ROW())))

    Yet another possibility is to use the OFFSET function:

    =IF(WEEKDAY(B7)<>6,"",SUM(OFFSET(H7,-6,0,7,1)))

    OFFSET(H7,-6,0,7,1) means: go 6 rows up from H7 and extend to a height of 7 rows.

    Both formulas will have the same result as the one from my first reply, but they are more complicated.

Posting Permissions

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