Excel 2016 - Conditional Formatting for Inventory Sheet

KaylaP

New Member
Joined
Aug 5, 2022
Messages
2
Office Version
  1. 2016
Platform
  1. Windows
I have an inventory spreadsheet that I am attempting to make more streamlined so that every time an inventory is completed, it is the same regardless of who completes the task. Setting up future generations for success and all that jazz. (And saving my sanity.)

1. Expiration dates column. Not all cells will have data. The blank cells should remain white.
2. If data exists, any expiration date within 2 months of expiring should turn the cell Yellow.
3. If data exists, any expiration date within the current month or past should turn the cell Red.
4. All other expiration dates will remain white.

Can anyone help with this? I've found a few promising solutions but none of them are working quite as intended.
 

Attachments

  • help1.png
    help1.png
    26.5 KB · Views: 7
  • help2.png
    help2.png
    22.8 KB · Views: 7
  • help3.png
    help3.png
    21.7 KB · Views: 7

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
1. Expiration dates column. Not all cells will have data. The blank cells should remain white.
2. If data exists, any expiration date within 2 months of expiring should turn the cell Yellow.
3. If data exists, any expiration date within the current month or past should turn the cell Red.
4. All other expiration dates will remain white.
setup 2 rules - one for yellow and 1 for red

I think you are using column K for the EXP date - but not sure

i can get confused with terms like within - expiring etc

RED
any date older than today and up to the end of the current month in the future
=AND( K2<>"", K2<=EOMONTH(TODAY(),0) )

YELLOW
Any day in the future 2 months
=AND( K2<>"", K2<=EOMONTH(TODAY(),1) )

NOW put in order red first - arrow top right can change order - and stop if true

Product-ETAF.xlsx
K
1
27/20/22
37/22/22
47/24/22
57/26/22
67/28/22
77/30/22
88/1/22
98/3/22
108/5/22
11
12
13
14
15
168/17/22
178/19/22
188/21/22
198/23/22
208/25/22
218/27/22
228/29/22
238/31/22
249/2/22
259/4/22
26
27
28
299/12/22
309/14/22
319/16/22
329/18/22
339/20/22
349/22/22
359/24/22
369/26/22
379/28/22
389/30/22
3910/2/22
40
41
42
Sheet4
Cells with Conditional Formatting
CellConditionCell FormatStop If True
K2:K50Expression=AND( K2<>"", K2<=EOMONTH(TODAY(),0) )textYES
K2:K43Expression=AND(K2<>"",K2<=EOMONTH(TODAY(),1))textYES


Note: Images are difficult to see , and also requires that I input all the data myself, which is very time consuming.

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC , then put the sample spreadsheet onto a share
I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed
 
Last edited:
Upvote 0
RED
any date older than today and up to the end of the current month in the future
=AND( K2<>"", K2<=EOMONTH(TODAY(),0) )

YELLOW
Any day in the future 2 months
=AND( K2<>"", K2<=EOMONTH(TODAY(),1) )

NOW put in order red first - arrow top right can change order - and stop if true
This worked like a charm! Thank you!!

I will be sure to follow your advice for future posts.
 
Upvote 0

Forum statistics

Threads
1,214,525
Messages
6,120,051
Members
448,940
Latest member
mdusw

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