Rick, Just try any text string under the first type 'Cell Value' is "A". I
have modified mine which passed the initial testing. It is time to have a
look at XL07..
'UDF to get Conditional Formatting Color Index for a cell (XL 2003
'-------------------------------------------------------------------------------
Function GetCFColorIndex(C As Range) As Variant
Dim intCount As Integer, FC As FormatCondition, blnMatch As Boolean
If C.Count <> 1 Then Exit Function
For intCount = 1 To C.FormatConditions.Count
'Loop through each Contidional Formatting
Set FC = C.FormatConditions(intCount)
If FC.Type = 1 Then
'Handle Type1-xlExpression (If 'Cell Value Is')
Select Case FC.Operator
Case xlBetween '1
If C.Value >= GetCFV(FC.Formula1) And C.Value _
<= GetCFV(FC.Formula2) Then blnMatch = True: Exit For
Case xlNotBetween '2
If C.Value < GetCFV(FC.Formula1) Or C.Value _
GetCFV(FC.Formula2) Then blnMatch = True: Exit For
Case xlEqual '3
If C.Value = GetCFV(FC.Formula1) Then blnMatch = True: Exit For
Case xlNotEqual '4
If C.Value <> GetCFV(FC.Formula1) Then blnMatch = True: Exit For
Case xlGreater '5
If C.Value > GetCFV(FC.Formula1) Then blnMatch = True: Exit For
Case xlGreaterEqual '6
If C.Value >= GetCFV(FC.Formula1) Then blnMatch = True: Exit For
Case xlLess '7
If C.Value < GetCFV(FC.Formula1) Then blnMatch = True: Exit For
Case xlLessEqual '8
If C.Value <= GetCFV(FC.Formula1) Then blnMatch = True: Exit For
End Select
Else
'Handle Type2-xlExternal (If 'Formula Is')
If Evaluate(FC.Formula1) Then blnMatch = True: Exit For
End If
Next
If blnMatch Then GetCFColorIndex = FC.Interior.ColorIndex
End Functio
'-------------------------------------------------------------------------------
Function GetCFV(strData As Variant)
'Get text string or numeric from CF formula
GetCFV = strData
If Not IsNumeric(strData) Then _
GetCFV = Mid(strData, 3, Len(strData) - 3)
End Functio
'-------------------------------------------------------------------------------
If this post helps click Yes