Conditional Format when calculation equals whole number

NWPhotoExplorer

New Member
Joined
Jan 19, 2021
Messages
34
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
I have a calculation that is adding up the values of some fields. I am trying to get it to highlight when the number it adds up to is a whole number, like 1, 2, 3, etc.
My calculation is =SUBTOTAL(9,T_JOBS[Hours (decimal)])

I tried using INT and MOD and some IF statements, but I am not coming up with anything that works. This has to be so simple, yet I've been struggling with it all day. Hopefully, someone out there knows how to do this!

Thanks in advance!
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
I have a calculation that is adding up the values of some fields. I am trying to get it to highlight when the number it adds up to is a whole number, like 1, 2, 3, etc.
My calculation is =SUBTOTAL(9,T_JOBS[Hours (decimal)])

I tried using INT and MOD and some IF statements, but I am not coming up with anything that works. This has to be so simple, yet I've been struggling with it all day. Hopefully, someone out there knows how to do this!

Thanks in advance!
Select the cell(s) that you want to be highlighted and add this formula via conditional formatting:

Excel Formula:
=IF(LEN(A1),MOD(A1,1)=0,"")

Change A1 to the cell you are referencing.
 
Upvote 0
I had run across that formula yesterday, but I can't seem to make it work. I'm not sure what the deal is. Here is a small sample of my table. I am working with time, so I wonder if that is the issue.

Job Tracker.xlsx
ABC
1Total Hours
21.00
3Start Time (hh:mm)End Time (hh:mm)Hours (decimal)
46:457:240.650
57:257:460.350
6
7FALSE
Sheet1
Cell Formulas
RangeFormula
C2C2=SUBTOTAL(9,Table1[Hours (decimal)])
C4:C5C4=([@[End Time (hh:mm)]]-[@[Start Time (hh:mm)]])*24
C7C7=IF(LEN(C2),MOD(C2,1)=0,"")
Cells with Conditional Formatting
CellConditionCell FormatStop If True
C2Expression=IF(LEN(C2),MOD(C2,1)=0,"")textNO
 
Upvote 0
Because of minor rounding discrepancies, C2 is actually 0.999999999999984, not 1.

I suggest you change C2: =ROUND(SUBTOTAL(9,Table1[Hours (decimal)]),N)

where N is your choice, say 2?
 
Upvote 0
Solution

Forum statistics

Threads
1,213,521
Messages
6,114,109
Members
448,548
Latest member
harryls

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