Consulting

Results 1 to 14 of 14

Thread: Solved: Simple Formatting

  1. #1
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location

    Solved: Simple Formatting

    Quick question. I am writing a macro to format the attached excel worksheet. I am trying to adjust this code:

    [VBA]Dim rng As Range, cell As Range, del As Range
    Set rng = Intersect(Range("A:A"), ActiveSheet.UsedRange)

    For Each cell In rng
    If (cell.Value) = "Block" Then

    Set del = cell
    Range(del, del.End(xlDown).Offset(-1, 0)).Select
    Range(Selection, Selection.Offset(0, 19)).Select

    With Selection.Interior
    .ThemeColor = xlThemeColorAccent1
    .TintAndShade = 0.799981688894314
    End With

    End If

    Next cell
    On Error Resume Next[/VBA]

    Instead of highlighting every instance the color indicated, I want to highlight every other instance of "block" (which has differing ranges - see Rows 8-14 and compare to Rows 4-5) starting at the second instance of "block" (Rows 6-7). Also, instead of highlighting the remaining area in the entire worksheet, is there a way to have it stop at the last instance? The first tab is what needs to be modified and the second tab is what I am trying to make it look like using this macro.

    Please let me know if I need to clarify and thanks very much for the help. If there is an entirely better way to do this than simply modifying the included code, I would love to see it. Thanks.

    Charles
    Attached Files Attached Files

  2. #2
    VBAX Regular
    Joined
    Feb 2011
    Posts
    75
    Location

    Hi-lite every other "Block"

    Hello Charles,

    one way I see is to cycle through the rows, and keep track of the cells with value "Block" in them. If that count is divisible by 2 without remainder, then color .... uh-oh, this may be tricky, because one block consist of 1 to n lines... let me see what I can do with it.

    Have a nice day, and a little patience please,
    Isabella

  3. #3
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location
    Thanks! Plenty of patience here. Let me know if you need anymore detail.

  4. #4
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    You could use conditional formatting with a formula of

    =MOD(COUNTIF(INDEX($A$4:OFFSET($A$1,MIN(IF($A5:$A$1000="Block",ROW($A5:$A$1 000)))-2,0),0,1),"Block"),2)=1
    ____________________________________________
    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
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Here is some VBA if you must be boring

    [vba]

    Public Sub ProcessData()
    Dim NumBlocks As Long
    Dim Lastrow As Long
    Dim i As Long

    With ActiveSheet

    Lastrow = .Cells(.Rows.Count, "A").End(xlUp).Row
    For i = 4 To Lastrow

    If .Cells(i, "A").Value = "Block" Then

    NumBlocks = NumBlocks + 1
    End If
    If NumBlocks Mod 2 = 1 Then

    .Rows(i).Interior.ColorIndex = 24
    End If
    Next i
    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

  6. #6
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location
    Thanks. I'll try it both ways. Never even thought of trying to tackle it with conditional formatting.

  7. #7
    Knowledge Base Approver VBAX Guru GTO's Avatar
    Joined
    Sep 2008
    Posts
    3,368
    Location
    [vba]If .Cells(i, "A").Value = "Block" Then

    NumBlocks = NumBlocks + 1
    End If
    If NumBlocks Mod 2 = 1 Then

    .Rows(i).Interior.ColorIndex = 24
    End If[/vba]

    Damn, that is just slick!

  8. #8
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location
    In the VBA, is there any way to stop the highlighting at Column T instead of the whole row?

  9. #9
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location
    Curious about NumBlocks...what is that actually representing/counting?

  10. #10
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by lukecj
    In the VBA, is there any way to stop the highlighting at Column T instead of the whole row?
    In the conditional formatting, just select the rows from column A to T.

    In the VBA, change

    [vba]

    If NumBlocks Mod 2 = 1 Then

    .Rows(i).Interior.ColorIndex = 24
    End If
    [/vba]

    to

    [vba]

    If NumBlocks Mod 2 = 1 Then

    .Cells(i, "A").Resize(, 20)Interior.ColorIndex = 24
    End If
    [/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
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by lukecj
    Curious about NumBlocks...what is that actually representing/counting?
    It counts the number of blocks of rows, rather than just the number of rows. It increments every time it hits a value of Block in column A.
    ____________________________________________
    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

  12. #12
    VBAX Regular
    Joined
    Feb 2010
    Posts
    41
    Location
    Thanks so much. This helps a lot. I appreciate the explanations.

  13. #13
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    For the code in Post #5, this change will restrict the formatting to the desired columns
    [VBA] With ActiveSheet.Columns("A:T")
    [/VBA]
    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'

  14. #14
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by mdmackillop
    For the code in Post #5, this change will restrict the formatting to the desired columns
    [VBA] With ActiveSheet.Columns("A:T")
    [/VBA]
    What a nice idea!
    ____________________________________________
    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

Posting Permissions

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