Consulting

Results 1 to 11 of 11

Thread: Solved: Tweak Macro Not To Eliminate Numbers

  1. #1
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location

    Solved: Tweak Macro Not To Eliminate Numbers

    In the attached workbook I have A/L in column C and when the macro fires if A/L is in column B the it copies it over.

    The problem I am having is that there is also numbers in column B, I don't want the numbers to be removed as this code is currently doing, how can I get it to only copy to the cells that have A/L and leave the other cells with numbers alone.
    Attached Files Attached Files

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

    Private Sub CommandButton2_Click()
    Dim Lastrow As Long

    With ActiveSheet

    With .UsedRange.Rows

    Lastrow = .Count + .Cells(1, 1).Row - 1
    End With

    With .Range("B5").Resize(Lastrow - 4).SpecialCells(xlCellTypeBlanks)

    .FormulaR1C1 = "=IF(RC[1]=""A/L"",""A/L"")"
    End With
    End With
    End Sub
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location
    Thanks xld, works fine just one small problem, can it be modified to skip blank cells in the range.

    Should have thought about that earlier.

    Thanks again.

  4. #4
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Do you mean this?

    [vba]

    Private Sub CommandButton2_Click()
    Dim Lastrow As Long
    Dim rng As Range

    With ActiveSheet

    With .UsedRange.Rows

    Lastrow = .Count + .Cells(1, 1).Row - 1
    End With

    On Error Resume Next
    Set rng = .Range("B5").Resize(Lastrow - 4).SpecialCells(xlCellTypeBlanks)
    On Error GoTo 0

    If Not rng Is Nothing Then

    With rng
    .FormulaR1C1 = "=IF(RC[1]=""A/L"",""A/L"","""")"
    End With
    End If
    End With
    End Sub
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  5. #5
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location
    Thanks xld, giving this some more thought, I think it would be better if I could steer away form the macro placing formulas down the column.

    If data is insertered later it will automatically fill the other column, which I don't want to happen.

    So I think a solution without inserting formulas would suit better in the long run if that is not to much of a problem to alter what has already been done.

    Thanks again

  6. #6
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

    Private Sub CommandButton2_Click()
    Dim Lastrow As Long
    Dim rng As Range

    With ActiveSheet

    With .UsedRange.Rows

    Lastrow = .Count + .Cells(1, 1).Row - 1
    End With

    On Error Resume Next
    Set rng = .Range("B5").Resize(Lastrow - 4).SpecialCells(xlCellTypeBlanks)
    On Error Goto 0

    If Not rng Is Nothing Then

    With rng
    .FormulaR1C1 = "=IF(RC[1]=""A/L"",""A/L"","""")"
    .Value = .Value
    End With
    End If
    End With
    End Sub [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  7. #7
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location
    Thanks again xld, Just one last request, can I add mutiplue criteria to the macro, my colleague has thrown up a senerio where two other factors maybe required to be entered. OFF and SICK that will be the last alteration, otherwise it's working as it should.

    Thankyou again

  8. #8
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    I assume that you mean

    [VBA]

    Private Sub CommandButton2_Click()
    Dim Lastrow As Long
    Dim rng As Range

    With ActiveSheet

    With .UsedRange.Rows

    Lastrow = .Count + .Cells(1, 1).Row - 1
    End With

    On Error Resume Next
    Set rng = .Range("B5").Resize(Lastrow - 4).SpecialCells(xlCellTypeBlanks)
    On Error Goto 0

    If Not rng Is Nothing Then

    With rng
    .FormulaR1C1 = "=IF(OR(RC[1]=""A/L"",RC[1]=""OFF"",RC[1]=""SICK"",RC[1],"""")"
    .Value = .Value
    End With
    End If
    End With
    End Sub [/VBA]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  9. #9
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location
    Thanks xld, the macro is stopping at this line
    [VBA].FormulaR1C1 = "=IF(OR(RC[1]=""A/L"",RC[1]=""OFF"",RC[1]=""SICK"",RC[1],"""")"[/VBA]

    runtime error 1004
    application defined or object defined error

    any thoughts

  10. #10
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Missing bracket

    [vba]

    Private Sub CommandButton2_Click()
    Dim Lastrow As Long
    Dim rng As Range

    With ActiveSheet

    With .UsedRange.Rows

    Lastrow = .Count + .Cells(1, 1).Row - 1
    End With

    On Error Resume Next
    Set rng = .Range("B5").Resize(Lastrow - 4).SpecialCells(xlCellTypeBlanks)
    On Error GoTo 0

    If Not rng Is Nothing Then

    With rng
    .FormulaR1C1 = "=IF(OR(RC[1]=""A/L"",RC[1]=""OFF"",RC[1]=""SICK""),RC[1],"""")"
    .Value = .Value
    End With
    End If
    End With
    End Sub
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  11. #11
    VBAX Tutor
    Joined
    Jan 2006
    Posts
    248
    Location
    Thanks xld now working, will mark as solved.

Posting Permissions

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