Column color fill

rjplante

Well-known Member
Joined
Oct 31, 2008
Messages
569
Office Version
  1. 365
Platform
  1. Windows
I have a table (see table below) and I have a row that has 5 dates in 5 consecutive columns. There is a blank row between each set of data. I have five months of columns, each month a block of five columns. I would like to have a macro that would start at column G and check to see if Date 1 fits the case for that column (30 days divided by 5 = 6, so Case 1 = Date <6). If date 1 fits case 1, then add the date to the cell and change to color based on the color matrix. If the date in the date 1 column does not fit the case for column G, move one cell to the right and see if date 1 fits into that date range. and loop through the remaining cells until it reaches the end of the last month. When Date 1 is done, loop through the cells for Date 2, etc, through Date 5. Then I need it to skip the blank row and repeat the process for each row with data in it.

I have included a set of date numbers that correspond to the month in the top row, located in the cells below the table. I was thinking that this might be helpful in solving the date checking component. I have worked out a way to do this, but I use a large If then statement to do just one month for one date. Doing it this way would be very slow and tedious as well as take up a lot of code. I know there has to be a more elegant way to write the code than what I have.


Here is what I have started with. NOTE: The cell references are off because I have created a more simplified table the my original.
My VBA Code:
VBA Code:
Dim VATDate As Date

VATDate = CDate(Range("J" & ActiveCell.Row))

If Month(VATDate) = Range("BG3").Value Then

    If Day(VATDate) <= 6 Then
    
        Range("R" & ActiveCell.Row).Interior.Color = RGB(255, 230, 150)
        Range("R" & ActiveCell.Row).Value = Range("J" & ActiveCell.Row).Value
        Range("S" & ActiveCell.Row).Select
        
    ElseIf Day(VATDate) > 6 And Day(VATDate) <= 12 Then
    
        Range("S" & ActiveCell.Row).Interior.Color = RGB(255, 230, 150)
        Range("S" & ActiveCell.Row).Value = Range("J" & ActiveCell.Row).Value
        Range("T" & ActiveCell.Row).Select
    
    ElseIf Day(VATDate) > 12 And Day(VATDate) <= 18 Then
    
        Range("T" & ActiveCell.Row).Interior.Color = RGB(255, 230, 150)
        Range("T" & ActiveCell.Row).Value = Range("J" & ActiveCell.Row).Value
        Range("U" & ActiveCell.Row).Select
    
    ElseIf Day(VATDate) > 18 And Day(VATDate) <= 24 Then
    
        Range("U" & ActiveCell.Row).Interior.Color = RGB(255, 230, 150)
        Range("U" & ActiveCell.Row).Value = Range("J" & ActiveCell.Row).Value
        Range("V" & ActiveCell.Row).Select
    
    ElseIf Day(VATDate) > 24 Then
    
        Range("V" & ActiveCell.Row).Interior.Color = RGB(255, 230, 150)
        Range("V" & ActiveCell.Row).Value = Range("J" & ActiveCell.Row).Value
        Range("W" & ActiveCell.Row).Select
    
    End If

End If

Data Table:

Book1
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAE
1Date 1Date 2Date 3Date 4Date 5Display DataMayJuneJulyAugustSeptember
2
31-Jun-202019-Jun-202026-Jun-20202-May-20201-Jul-2020
4
513-Jul-202025-Jul-20204-Aug-202013-Aug-202020-Aug-2020
6
71-Aug-202015-Aug-202022-Aug-20206-Sep-202011-Sep-2020
8
9
10
11
12Case 1Case 2Case 3Case 4Case 5
13Case 1Date < 6
14Case 2Date > 6 AND Date <= 12ColorRGB
15Case 3Date > 12 AND Date <= 18Date 1255250150
16Case 4Date > 18 AND Date <= 24Date 2215240200
17Case 5Date > 24Date 3255215215
18Date 4200215240
19Date 5255220255
20
21Month Numbers56789
Sheet1
Cell Formulas
RangeFormula
G1G1=TEXT(TODAY(),"mmmm")
L1L1=TEXT(EDATE(TODAY(),BA1+1),"mmmm")
Q1Q1=TEXT(EDATE(TODAY(),BA1+2),"mmmm")
V1V1=TEXT(EDATE(TODAY(),BA1+3),"mmmm")
AA1AA1=TEXT(EDATE(TODAY(),BA1+4),"mmmm")
C3C3=IF(OR(B3="",B3="TBD"),"",B3+7)
G21G21=MONTH(TODAY())
H21:K21H21=G21+1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
E3Expression=$C3="Bob"textNO
E3Expression=$C3="Bob"textNO
E3Expression=$C3="Andrew"textNO
E3Expression=$C3="Amber"textNO
E3Expression=$C3="Robert"textNO
E3Expression=$C3="Andrew"textNO
E3Expression=$C3="Amber"textNO
A3:E10Expression=$C3="Bob"textNO
A3:E10Expression=$C3="Bob"textNO
A3:E10Expression=$C3="Andrew"textNO
A3:E10Expression=$C3="Amber"textNO
A3:E10Expression=$C3="Robert"textNO
A3:E10Expression=$C3="Andrew"textNO
A3:E10Expression=$C3="Amber"textNO


Thanks for the help.
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
Dante Amor
ABCDEFGHIJKLMNOPQRSTU
1Date 1Date 2Date 3Date 4Date 5Display Datamayjunjul
2
301/jun/202019/jun/202026/jun/202002/may/202001/jul/2020BobBobBobBobBobBob
4
513/jul/202002/jul/202004/ago/202013/ago/202020/ago/2020AmorAmorAmor
6
701/ago/202015/ago/202022/ago/202006/sep/202011/sep/2020Andrew
8
Hoja4


The macro works considering your example, just like the example above.
- The abbreviated name of the month (May, Jun, Jul, etc.), will be searched in row 1.
- The day of the month will be divided by 6 to obtain only 5 weeks per month.
- The color will be obtained from cells A1 to E1.
Try the following:

VBA Code:
Sub Column_color_fill()
  Dim lr As Long, c  As Range, f As Range, m As String, n As Long
  
  lr = Range("A" & Rows.Count).End(3).Row
  Range("G3:BZ" & lr).ClearContents
  Range("G3:BZ" & lr).Interior.Color = xlNone
  
  For Each c In Range("A3:E" & lr).SpecialCells(xlCellTypeConstants)
    m = MonthName(Month(c.Value), True)
    n = WorksheetFunction.RoundUp(Day(c.Value) / 6, 0) - 1
    If n > 4 Then n = 4
    Set f = Rows(1).Find(m, , xlValues, xlWhole)
    If Not f Is Nothing Then
      With Cells(c.Row, f.Column + n)
        .Value = Cells(c.Row, "F")
        .Interior.Color = Cells(1, c.Column).Interior.Color
      End With
    End If
  Next
End Sub
 
Last edited:
Upvote 0
Dante,

My apologies as I did not fill in the table the way I wanted it displayed. I have included the updated table below. I believe it may modify your code when you see the output results I am looking for. I wanted the day and month (dd-mmm) in the colored cell. If there is a date in that column, I want the date in the correct month column with the cell colored. If there is no date, no color in the calendar section.


Updated Table:
Book1
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAE
1Date 1Date 2Date 3Date 4Date 5Display DataMayJuneJulyAugustSeptember
2
31-Jun-202019-Jun-202026-Jun-20202-May-20201-Jul-20202-May1-Jun19-Jun26-Jun1-Jul
4
513-Jul-202025-Jul-20204-Aug-202013-Aug-202020-Aug-202013-Jul25-Jul3-Aug13-Aug20-Aug
6
71-Aug-202015-Aug-202022-Aug-202011-Sep-20201-Aug15-Aug22-Aug11-Sep
8
9
10
Sheet1
Cell Formulas
RangeFormula
G1G1=TEXT(TODAY(),"mmmm")
L1L1=TEXT(EDATE(TODAY(),BA1+1),"mmmm")
Q1Q1=TEXT(EDATE(TODAY(),BA1+2),"mmmm")
V1V1=TEXT(EDATE(TODAY(),BA1+3),"mmmm")
AA1AA1=TEXT(EDATE(TODAY(),BA1+4),"mmmm")
C3C3=IF(OR(B3="",B3="TBD"),"",B3+7)
Cells with Conditional Formatting
CellConditionCell FormatStop If True
E3Expression=$C3="Bob"textNO
E3Expression=$C3="Bob"textNO
E3Expression=$C3="Andrew"textNO
E3Expression=$C3="Amber"textNO
E3Expression=$C3="Robert"textNO
E3Expression=$C3="Andrew"textNO
E3Expression=$C3="Amber"textNO
A3:E10Expression=$C3="Bob"textNO
A3:E10Expression=$C3="Bob"textNO
A3:E10Expression=$C3="Andrew"textNO
A3:E10Expression=$C3="Amber"textNO
A3:E10Expression=$C3="Robert"textNO
A3:E10Expression=$C3="Andrew"textNO
A3:E10Expression=$C3="Amber"textNO
 
Upvote 0
Sorry that was for someone else, I got confused and posted it here.
 
Upvote 0
I wanted the day and month (dd-mmm) in the colored cell.
Try this

VBA Code:
Sub Column_color_fill()
  Dim lr As Long, c As Range, f As Range, m As String, n As Long
  
  lr = Range("A" & Rows.Count).End(3).Row
  Range("G3:BZ" & lr).ClearContents
  Range("G3:BZ" & lr).Interior.Color = xlNone
  
  For Each c In Range("A3:E" & lr).SpecialCells(xlCellTypeConstants)
    m = MonthName(Month(c.Value))
    n = WorksheetFunction.RoundUp(Day(c.Value) / 6, 0) - 1
    If n > 4 Then n = 4
    Set f = Rows(1).Find(m, , xlValues, xlWhole)
    If Not f Is Nothing Then
      With Cells(c.Row, f.Column + n)
        .Value = c.Value
        .Interior.Color = Cells(1, c.Column).Interior.Color
      End With
    End If
  Next
End Sub
 
Upvote 0
In my table, I only have five months displayed, starting with the month the matches today. When I run your code it fills in a couple of cells, but they are off of the table with the dates in them. Then the macro crashes on the line "m = MonthName(Month(c.Value), True)" with the error "Run-Time error '13': Type mismatch." I don't know why this is happening, nor how to fix it.
 
Upvote 0
in the range of cells in row 3 and down and in columns A through E, only dates should exist.
 
Upvote 0
To validate dates in the range of columns A to E.
Try this,

VBA Code:
Sub Column_color_fill()
  Dim lr As Long, c As Range, f As Range, m As String, n As Long
  
  lr = Range("A" & Rows.Count).End(3).Row
  Range("G3:BZ" & lr).ClearContents
  Range("G3:BZ" & lr).Interior.Color = xlNone
  
  For Each c In Range("A3:E" & lr).SpecialCells(xlCellTypeConstants)
    If c.Value <> "" And IsDate(c.Value) Then
      m = MonthName(Month(c.Value))
      n = WorksheetFunction.RoundUp(Day(c.Value) / 6, 0) - 1
      If n > 4 Then n = 4
      Set f = Rows(1).Find(m, , xlValues, xlWhole)
      If Not f Is Nothing Then
        With Cells(c.Row, f.Column + n)
          .Value = c.Value
          .Interior.Color = Cells(1, c.Column).Interior.Color
        End With
      End If
    End If
  Next
End Sub
 
Upvote 0
Dante,

We are getting close. When I run the code now I get no crashes with any of the code. Thumbs up. On my actual spreadsheet the range I have with all my date in it is (J5:N & lr) The range of cells where I want the dates and color to fill in is from R5:AP105. I have adjusted the code you supplied to reflect these changes. When I run the code. None of the dates appear in the R:AP range of cells. There are cells in the range from BF:BL that do get colored and have the dates put in them. Not all of the dates get added there, but at least some of them do. Also I do not know why it starts at column BF and ends at BL. I have included your code with my range updates below.

VBA Code:
Sub Column_color_fill()
  
  
  Dim lr As Long, c  As Range, f As Range, m As String, n As Long
  
  lr = Range("A" & Rows.Count).End(3).Row
  Range("R5:AP" & lr).ClearContents
  Range("R5:AP" & lr).Interior.Color = xlNone
  
  For Each c In Range("J5:N" & lr).SpecialCells(xlCellTypeConstants)
    If c.Value <> "" And IsDate(c.Value) Then
      m = MonthName(Month(c.Value))
      n = WorksheetFunction.RoundUp(Day(c.Value) / 6, 0) - 1
      If n > 4 Then n = 4
      Set f = Rows(1).Find(m, , xlValues, xlWhole)
      If Not f Is Nothing Then
        With Cells(c.Row, f.Column + n)
          .Value = c.Value
          .Interior.Color = Cells(1, c.Column).Interior.Color
        End With
      End If
    End If
  Next
 
End Sub

What do I need to do to get this fixed. Your code is awesome and very few lines to get what I need done. I hope someday to be able to understand the tools you are using to achieve this as it is pretty cool.
 
Upvote 0

Forum statistics

Threads
1,215,219
Messages
6,123,680
Members
449,116
Latest member
HypnoFant

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