Format cells based on row and column references

Minx_Minxy

New Member
Joined
Jul 13, 2015
Messages
16
Office Version
  1. 365
Platform
  1. Windows
Hello,

I have a file with 2 sheets Named:

Holiday Calendar

Book1.xlsm
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAHAIAJ
12022
2BHBank Holiday UK&IBHBank Holiday UKBHBank Holiday IrelandHoliday
3
4January
5Carried FwdIn LieuEntitledLeft OverSatSunMonTueWedThuFriSatSunMonTueWedThuFriSatSunMonTueWedThuFriSatSunMonTueWedThuFriSatSunMon
6Name01020304050607080910111213141516171819202122232425262728293031
7JoeBH11
8SmithBH1110.5
9SamBH
10JohnBH
11KarenBH111
12HarryBH10.5
13KevinBH
14
15
16February
17Carried FwdIn LieuEntitledLeft OverTueWedThuFriSatSunMonTueWedThuFriSatSunMonTueWedThuFriSatSunMonTueWedThuFriSatSunMon
18Name01020304050607080910111213141516171819202122232425262728
19Joe
20Smith
21Sam11111
22John
23Karen
24Harry0.51
25Kevin
Holiday Calendar




And Daily Planner

Book1.xlsm
ABCDEFGHIJKLMNO
1MondayTuesdayWednesdayThursdayFridaySaturdaySunday
2Joe03 - Jan04 - Jan05 - Jan06 - Jan07 - Jan08 - Jan09 - Jan
3SmithHalf Day
4Sam
5John
6Karen
7Harry
8Kevin
9Joe10 - Jan11 - Jan12 - Jan13 - Jan14 - Jan15 - Jan16 - Jan
10Smith
11Sam
12John
13Karen
14Harry
15Kevin
Daily Planner




What I need is when 1 is entered in Holiday Calendar, then the corresponding cell in Daily planner is filled with blue. If 0.5 is entered then it turns blue and mentions Half Day. For example, Smith is on holiday from the 04th to 06th and half a day on 07th of January in the Holiday calendar (cells I8:L8), so in the Daily Planner for the corresponding days the cells are formatted blue from 04th to 06th of January and on the 07th is blue + Half Day on it (cells E3,G3,I3,K3)

I would like it applied for all 12 months of the year, both sheets are setup like the ranges provided up till the end of 2022.

I don't believe conditional formatting supports this. If it does how do I do it?

I have very little knowledge in macro but I am willing to use it if would suit best for this situation.
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
It looks to me like your big problem is that the first sheet is organized by month and the second sheet is organized by week. If they were organized the same way you could definitely use conditional formatting do this. But the way you have it makes it very difficult to start with a person/date on the second sheet and find the corresponding cell on the first sheet.

Another problem is using merged cells in the second sheet. Merged cells nearly always cause problems and in this case they will.

One thing that is fortunate is that the dates are actual Excel dates so they can be compared. Another suggestion is to also make the days in Holiday Calendar refer to the actual dates and format them as "Ddd" so you don't have to manually change them for every month.

This user-defined function (UDF) should work but I had to re-create your file from scratch to test it. Then you would use this in a conditional formatting rule.

See linked file for example using your mock-up.


That is a dropbox link and is not guaranteed to be here forever.

VBA Code:
Option Explicit

Public Function IsOnHoliday(Cell As Range) As Variant
  
   Dim R As Long, C As Long
   Dim HolidayDate As Range
   Dim DateCell As Range
   Dim LastRow As Long
  
   If Cell.Count > 1 Then
      IsOnHoliday = "#RANGE!"
   Else

      ' Find the date
      Set DateCell = Cell.Offset(0, -1)
      Do Until DateCell > 0
         Set DateCell = DateCell.Offset(-1, 0)
      Loop
     
      ' Now find the corresponding date in Holiday Calendar
      R = 1

      With Worksheets("Holiday Calendar")
     
         ' Find the date
        
         LastRow = .Cells(.Rows.Count, "A").End(xlUp).Row
         Do
            ' Find the date row of the next month
            Do
               R = R + 1
            Loop Until IsDate(.Cells(R, "F")) Or R > LastRow
           
            If R > LastRow Then Exit Do
           
            ' See if the desired date has a match in this month
            Set HolidayDate = .Rows(R).Find(what:=CDate(DateCell), LookIn:=xlFormulas, lookat:=xlWhole)
        
         Loop Until Not HolidayDate Is Nothing
        
         If R > LastRow Then
            IsOnHoliday = "#DATE!"
            Exit Function
         End If
        
         ' Find the person
         Do Until .Cells(R, "A") = Cell.Parent.Cells(Cell.Row, "A")
            R = R + 1
         Loop
        
         IsOnHoliday = IsNumeric(.Cells(R, HolidayDate.Column).Value) And .Cells(R, HolidayDate.Column).Value > 0
        
      End With
   End If

End Function

Private Sub test()

   Debug.Print IsOnHoliday(Sheet16.Range("E3"))  

End Sub
 
Upvote 0
Solution
Hi StringJazzer, thank you for the feedback regarding the merging cells, I'll keep it mind next time!

Apologies in advance, my knowledge in macro is very limited, do I have to change anything when I copy the code to the sheet I need? If so what is it?

Will it automatically work as information is entered? Or do I have to assign to an object like button?
 
Upvote 0
Hello StringJazzer,

I went back to your answer! My apologies for overseeing that the code has been applied on the conditional formatting. However, on the spreadsheet you've provided I tried to test it by adding 1s to other cells in the Holiday Calendar but the cells in the Planner aren't turning blue.

What should I be doing to make it work?
 
Upvote 0
The code must be placed in a standard module. If you do not have any modules, create one and its name will default to Module1. The code will not work if you put it in a worksheet module.

All of this is demonstrated in the file I linked.
 
Upvote 0

Forum statistics

Threads
1,215,453
Messages
6,124,920
Members
449,195
Latest member
Stevenciu

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