Consulting

Results 1 to 4 of 4

Thread: Code to fill a column range with conditional formatting is using absolute reference

  1. #1
    VBAX Expert
    Joined
    Sep 2010
    Posts
    604
    Location

    Code to fill a column range with conditional formatting is using absolute reference

    When I manually enter the formula shown in this code into Cell B16
    and then use the format painter to copy it down my column range it correctly uses relative references

    But when I try to do it in code, it is incorrectly using an absolute reference.

    What am I doing wrong?

    Sample Workbook attached
    [vba]Sub Add__Conditional_Formating()

    ActiveSheet.Unprotect

    Dim wks As Worksheet

    Set wks = ActiveSheet

    With wks

    Lastrow = .[B65536].End(xlUp).Row

    Set rng = .Range("B16:B" & Lastrow)

    End With

    Application.ScreenUpdating = False

    Application.EnableEvents = False

    rng.FormatConditions.Delete

    With Range("B16")

    .FormatConditions.Add Type:=xlExpression, Formula1:= _
    """=IF(ISNUMBER(--(SUBSTITUTE($B15,""""-"""",0))),IF(ISNUMBER(FIND(""""-"""",$B16)), --(SUBSTITUTE($B16,""""-"""",0)), $B16*100)> IF(ISNUMBER(FIND(""""-"""",$B15)), --(SUBSTITUTE($B15,""""-"""",0)),$B15*100))"""

    .FormatConditions(1).Font.ColorIndex = 3

    .Copy

    End With

    rng.PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
    SkipBlanks:=False, Transpose:=False

    Application.CutCopyMode = False

    'Range("G24").Select
    Application.EnableEvents = True

    Application.ScreenUpdating = True
    End Sub[/vba] Edit: Will it work if I use a loop to add the formula in each cell ?
    * I did try that already with the same result, but if an expert thinks that is what's needed, I'll try again, as perhaps I implemented it wrong with my 1st try.
    Attached Files Attached Files
    Last edited by frank_m; 02-19-2011 at 04:17 PM.

  2. #2
    VBAX Expert shrivallabha's Avatar
    Joined
    Jan 2010
    Location
    Mumbai
    Posts
    750
    Location
    Just an opinion, untested. Did you try changing this (in red):
    [VBA]
    .FormatConditions.Add Type:=xlExpression, Formula1:= _
    """=IF(ISNUMBER(--(SUBSTITUTE($B15,""""-"""",0))),IF(ISNUMBER(FIND(""""-"""",$B16)), --(SUBSTITUTE($B16,""""-"""",0)), $B16*100)> IF(ISNUMBER(FIND(""""-"""",$B15)), --(SUBSTITUTE($B15,""""-"""",0)),$B15*100))""" [/VBA]
    To this:
    [VBA]
    .FormatConditions.Add Type:=xlExpression, Formula1:= _
    "=IF(ISNUMBER(--(SUBSTITUTE($B15,""""-"""",0))),IF(ISNUMBER(FIND(""""-"""",$B16)), --(SUBSTITUTE($B16,""""-"""",0)), $B16*100)> IF(ISNUMBER(FIND(""""-"""",$B15)), --(SUBSTITUTE($B15,""""-"""",0)),$B15*100))"[/VBA]
    Regards,
    --------------------------------------------------------------------------------------------------------
    Shrivallabha
    --------------------------------------------------------------------------------------------------------
    Using Excel 2016 in Home / 2010 in Office
    --------------------------------------------------------------------------------------------------------

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    I agree with shrivallabha, but you need to go much further, you have far too many quotes in ther.

    Use

    [vba]

    "=IF(ISNUMBER(--(SUBSTITUTE($B15,""-"",0))),IF(ISNUMBER(FIND(""-"",$B16)), --(SUBSTITUTE($B16,""-"",0)), $B16*100)> IF(ISNUMBER(FIND(""-"",$B15)), --(SUBSTITUTE($B15,""-"",0)),$B15*100))"
    [/vba]

    As an aside, you should avoid hard-coding wherever possible, so don't use

    [vba]

    Lastrow = .[B65536].End(xlUp).Row[/vba]

    but use

    [vba]

    Lastrow = .Cells(.Rows.Count, "B").End(xlUp).Row[/vBa]

    (I also removed that nasty [cell] syntax!).
    ____________________________________________
    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

  4. #4
    VBAX Expert
    Joined
    Sep 2010
    Posts
    604
    Location
    Hi shrivallabha, thanks for sharing your wisdom that is far above mine.

    Hi Bob - Using the formula as you presented it, with fewer quote's (than what the macro recorder gave me), however it still resulted in absolute references, instead of relative.(when using it in my version of code) -- I googled a bit and found a piece of your code (I think at Mr Excel) and it works

    Thanks

    [vba]Sub Add_Conditional_Formating()

    'This code works correctly

    Dim Lastrow As Long
    Dim i As Long

    Dim wks As Worksheet

    Set wks = ActiveSheet

    With wks
    Lastrow = ActiveSheet.Cells(.Rows.Count, "B").End(xlUp).Row
    End With

    Application.EnableEvents = False

    Range("B16").Select 'I'm clueless, but without B16 selected I occasionally get incorrect references

    For i = 1 To Lastrow - 1 'I'm also clueless as to why 16 To Lastrow won't work (16 is my 1st Row)
    With Range("B" & i + 2)
    .FormatConditions.Delete
    .FormatConditions.Add Type:=xlExpression, _
    Formula1:="=IF(ISNUMBER(--(SUBSTITUTE($B15,""-"",0))),IF(ISNUMBER(FIND(""-"",$B16)), --(SUBSTITUTE($B16,""-"",0)), $B16*100)> IF(ISNUMBER(FIND(""-"",$B15)), --(SUBSTITUTE($B15,""-"",0)),$B15*100))"
    .FormatConditions(1).Font.ColorIndex = 3
    End With
    Next i

    Application.EnableEvents = True

    End Sub
    [/vba]
    Attached Files Attached Files

Posting Permissions

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