Consulting

Results 1 to 6 of 6

Thread: Solved: vary column

  1. #1
    VBAX Regular
    Joined
    Oct 2012
    Location
    Iasi, Romania
    Posts
    18
    Location

    Solved: vary column

    Hello,

    I have the following script:

    [VBA]
    For i = 1 To nrFTE
    For j = 0 To nrCat
    maxRow = Range("AB7").Offset(nrAtt, 0).Row
    totform = "=SUM(AB7:AB" & maxRow - 1 & ")"
    Range("AB" & nrAtt + 7).Offset(0, (i - 1)) = totform
    Next
    Next
    [/VBA]

    All I want to do is to set the column as a variable in the SUM formula...practically I want to have a variable number of sums in which the column changes (ex. AB7:AB23, AC7:AC32, AD7:AD32, etc.).

    Any ideas?

    Thank you for your support!

  2. #2
    VBAX Mentor Teeroy's Avatar
    Joined
    Apr 2012
    Location
    Sydney, Australia
    Posts
    414
    Location
    The following chages to your script will make everything relative to a range object (rFirstCell) rather than a cell position (Untested).

    [vba]For i = 1 To nrFTE
    Set rFirstCell = Range("AB7")
    sCol = Split(rFirstCell.Address, "$")(1)
    For j = 0 To nrCat
    maxRow = rFirstCell.Offset(nrAtt, 0).Row
    totform = "=SUM(" & rFirstCell.Address & ":" & sCol & maxRow - 1 & ")"
    Range(sCol & nrAtt + 7).Offset(0, (i - 1)) = totform
    Next
    Next
    [/vba]
    _________________________________________________________________________
    "In theory there is no difference between theory and practice. In practice there is." - Chuck Reid

    Any day you learn something new is a day not wasted.

  3. #3
    VBAX Regular
    Joined
    Oct 2012
    Location
    Iasi, Romania
    Posts
    18
    Location
    To be more clear I attached the file. As you can see the formula it's ok on AB33 because it makes the sum of the cells AB7:AB32. But in the cell AC33 I have the same formula instead of AC7:AC32 and so on for the rest of cells AD33, AE33, etc.
    This is the reason why I asked to vary the column letters and to keep the number, because I want to multiply horizontally the formula.

    Can you help me?

    PS: The code which does not work is written in brackets "----------------------"

    Thanks!
    Attached Files Attached Files

  4. #4
    VBAX Mentor Teeroy's Avatar
    Joined
    Apr 2012
    Location
    Sydney, Australia
    Posts
    414
    Location
    Sorry I mustn't have made myself clear, you need to move the range object as you go. Now that I can see what your variables do you can replace:
    [vba] '--------------------------
    For i = 1 To nrFTE * nrCat
    For j = 0 To nrCat
    maxRow = Range("AB7").Offset(nrAtt, 0).Row
    totform = "=SUM(AB7:AB" & maxRow - 1 & ")"
    Range("AB" & nrAtt + 7).Offset(0, (i - 1)) = totform
    Next
    Next
    '--------------------------[/vba]
    With

    [vba] Dim rng As Range
    Dim rng1 As Range

    Set rng1 = Range("AB7").Resize(1, nrFTE * nrCat - 1)
    For Each rng In rng1
    rng.Offset(nrAtt, 0).Formula = "=sum(" & _
    Range(rng, rng.Offset(nrAtt - 1, 0)).Address & ")"
    Next[/vba]
    _________________________________________________________________________
    "In theory there is no difference between theory and practice. In practice there is." - Chuck Reid

    Any day you learn something new is a day not wasted.

  5. #5
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,873
    …or by one line:[VBA]Range("AB7").Offset(nrAtt).Resize(, nrFTE * nrCat).FormulaR1C1 = "=SUM(R[-" & nrAtt & "]C:R[-1]C)"[/VBA]
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  6. #6
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,873
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

Posting Permissions

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