Consulting

Results 1 to 4 of 4

Thread: Conditional Formatting with a Named Range

  1. #1
    VBAX Regular
    Joined
    Apr 2009
    Posts
    9
    Location

    Conditional Formatting with a Named Range

    I am trying to apply conditional formatting to a range called CallTable. I would like to highlight each row in the range where the value in column k is not equal to 0.

    Currently I am using the below, which is producing some odd results. For example if I highlight the CallTable range after the code has run and check the conditional formatting formula, I am seeing a different result every time with the cell location being somewhere near the bottom or the page, such as =$K65523<>0 instead of the correct =$K3<>0

    Is there something that I am missing?

    [VBA]With wksDataDest.Range("CallTable")
    .Style = "tblCall"
    With .FormatConditions
    .Delete
    .Add Type:=xlExpression, Formula1:="=$K3<>0"
    .Item(1).Interior.ColorIndex = 36
    End With
    End With[/VBA]

  2. #2
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    I can't replicate this. Can you post your workbook?
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

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

    With wksDataDest

    .Range("K3").Select
    With .Range("CallTable")
    .Style = "tblCall"
    With .FormatConditions
    .Delete
    .Add Type:=xlExpression, Formula1:="=$K3<>0"
    .Item(1).Interior.ColorIndex = 36
    End With
    End With
    End With
    [/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

  4. #4
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    To avoid selecting you could use either of these two techniques, one of which is commented out. I'm a bit surprised that CF doesn't take R1C1 notation directly.
    [VBA]Dim conditionFormula As String

    With Range("CallTable")
    'conditionFormula = "=$K" & .Row & "<>0"

    With .FormatConditions
    .Delete
    .Add Type:=xlExpression, Formula1:=Application.ConvertFormula("=RC11<>0", xlR1C1, xlA1, False, Range("calltable"))
    '.Add Type:=xlExpression, Formula1:=conditionFormula
    .Item(1).Interior.ColorIndex = 36
    End With
    End With[/VBA]

Posting Permissions

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