Code To Highlight Row When Data Is In AA

Dazzawm

Well-known Member
Joined
Jan 24, 2011
Messages
3,783
Office Version
  1. 365
Platform
  1. Windows
Hi. I need a code please that will highlight a single row according to C when there is data in AA. As you can see below rows 2, 6, 7 ,8 and 11 are single rows (groups of more than one row can be ignored like 3-5 and 9-10)

Book1
CAA
1CatCode
2AUA314 1022Data
3AUA618 2012
4AUA618 2012
5AUA618 2012
6AUA618 3012
7AUA620 2008
8AUA620 2017Data
9AUA620 3008
10AUA620 3008
11AUA620 3014
Sheet1


Below you can see rows 2 and 8 have data in AA so need highlighting, rows 6, 7 and 11 have no data in AA so don't need highlighting. It will be used on various files up to 100,000 rows and there may be groups of rows matching in C up to about 20. I have hidden other columns for clarity.

Book1
CAA
2AUA314 1022Data
3AUA618 2012
4AUA618 2012
5AUA618 2012
6AUA618 3012
7AUA620 2008
8AUA620 2017Data
9AUA620 3008
10AUA620 3008
11AUA620 3014
Sheet1


Thanks.
 
Hi @Dazzawm.


I hope I understand your request correctly, try the following code:

VBA Code:
Sub Highlight_Row()
  Dim dic As Object, rng As Range, a, ky, i&
 
  Set dic = CreateObject("Scripting.Dictionary")
  a = Range("C1:AA" & Range("C" & Rows.Count).End(3).Row).Value2
  Set rng = Range("C1")
 
  For i = 2 To UBound(a, 1)
    If Not dic.exists(a(i, 1)) Then
      'Only consider when there is data in AA
      If a(i, 25) = "" Then dic(a(i, 1)) = 0 Else dic(a(i, 1)) = i
    Else
      dic(a(i, 1)) = 0
    End If
  Next
 
  For Each ky In dic.keys
    If dic(ky) <> 0 Then
      Set rng = Union(rng, Range("A" & dic(ky) & ":AA" & dic(ky)))
    End If
  Next
  rng.Interior.Color = vbYellow
  Range("C1").Interior.ColorIndex = xlNone
End Sub


--------------
Let me know the result and I'll get back to you as soon as I can.
Sincerely
Dante Amor
--------------
That does exactly as I need, much obliged squire.
 
Upvote 0

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Use conditional formatting to highlight the entire row starting @ row 2 with formula:
Excel Formula:
=IF(OR(NOT(ISBLANK($AA2)),"Data"=$AA2),TRUE,FALSE)

In your formula is not necessary that IF, could be only:

in CF =and(not(isblank($aa2), $aa2="DATA")

If I understand correctly what op wants then:
in CF =and(Unique($c2), $aa2="DATA")
 
Last edited:
Upvote 0
Does this work:
mr excel questions 25.xlsm
CAAABAC
1CatCode
2AUA314 1022DataTRUE
3AUA618 2012FALSE
4AUA618 2012FALSE
5AUA618 2012FALSE
6AUA618 3012FALSE
7AUA620 2008FALSE
8AUA620 2017DataTRUE
9AUA620 3008FALSE
10AUA620 3008FALSE
11AUA620 3014FALSE
dazzawm
Cell Formulas
RangeFormula
AB2:AB11AB2=IF($AA2<>"",COUNTIF($C$2:$C$11,C$2)=1)
Cells with Conditional Formatting
CellConditionCell FormatStop If True
3:11Expression=IF($AA3<>"",COUNTIF($C$2:$C$11,$C3)=1)textNO
2:2Expression=IF($AA2<>"",COUNTIF($C$2:$C$11,$C2)=1)textNO
 
Upvote 0
In your formula is not necessary that IF, could be only:

in CF =and(not(isblank($aa2), $aa2="DATA")

If I understand correctly what op wants then:
in CF =and(Unique($c2), $aa2="DATA")
No they later said could be any data so would be the OR condition, and true on the IF statement, I usually add for readability . . .
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,337
Members
452,637
Latest member
Ezio2866

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top