Written by Allen Wyatt (last updated November 8, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Graham uses a formula that references two cells, B1 and C1. All the formula does is to return the value of one of the cells, as in =IF(A1=1,IF(B1>C1,B1,C1)). Both B1 and C1 normally contain dates, but sometimes either or both of them may be empty. If they are both empty, the returned value (which is 0 because they are empty) shows up as 1/0/1900. When both cells are empty Graham would like the formula to return a blank value, not a 0.
There are several ways that this need can be approached. First, though, let's start with Graham's example formula:
=IF(A1=1, IF(B1>C1, B1, C1))
The formula is a bit "incomplete," as it doesn't provide what should be returned if A1 does not contain the value 1. As written, if A1 contains 2 (or any other value except 1), then the formula returns "FALSE". So, let's modify the formula just a bit so that if A1 is not 1 that it returns a "blank" value, like this:
=IF(A1=1, IF(B1>C1, B1, C1), "")
Next it is key to understand what is happening in the "B1>C1" comparison. Dates are, of course, stored internally as numeric values—as serial numbers. If B1 contains a date that is more recent than C1, then the serial number in B1 will be larger than the serial number in C1. Beyond this, the characteristics of the data in B1 and C1 determine how the comparison (>) works.
Based on this, if one cell contains a date and the other is empty it is equivalent to comparing a serial number (the date) against a 0 (the empty cell), so the serial number will always be greater than the empty cell. If both cells are empty, both are treated as containing 0, and therefore both are equal.
So, let's say that in Graham's formula, cell A1 contains the value 1, cell B1 is empty, and cell C1 is empty. This is how the formula is "translated" by Excel:
=IF(A1=1, IF(B1>C1, B1, C1), "") =IF(1=1, IF(B1>C1, B1, C1), "") =IF(B1>C1, B1, C1) =IF(0>0, B1, C1) =C1 =0
This is why Graham is seeing 0 returned by the formula, and when 0 is considered to be a date serial number, it is displayed as 1/0/00 (or 1/0/1900).
To avoid this, you need to check to see if both B1 and C1 are empty. There are any number of ways this can be done. Consider this variation on his formula:
=IF(A1=1, IF((B1+C1=0), "", IF(B1>C1, B1, C1)), "")
This variation adds an IF statement to see if B1 added to C1 is equal to 0, which it will be if both of them are blank because Excel considers the blanks and 0 to be equivalent in this context. The drawback is that if either B1 or C1 contains a text value, then the #VALUE error is returned by the formula.
A better variation may be the following:
=IF(A1=1, IF(AND(B1=0,C1=0), "", IF(B1>C1, B1, C1)), "")
In this incarnation the IF statement uses the AND function to determine if both B1 and C1 are 0. This also solves the potential #VALUE error issue.
If you really want to check whether both B1 and C1 are empty, then you'll need to rely on a different approach. One way is to use the COUNTA function:
=IF(A1=1, IF(COUNTA(B1:C1)=0, "", IF(B1>C1, B1, C1)), "")
If you know for a fact that both B1 and C1 will never contain text values at the same time, you could also use the COUNT function in place of the COUNTA function in the foregoing formula.
Another approach is to use the COUNTBLANK function in much the same way; it returns a count of the number of cells in a range that are empty:
=IF(A1=1, IF(COUNTBLANK(B1:C1)=2, "", IF(B1>C1, B1, C1)), "")
A similar variation is to use the ISBLANK function (which returns TRUE if a cell is blank) along with the AND function:
=IF(A1=1, IF(AND(ISBLANK(B1), ISBLANK(C1)), "", IF(B1>C1, B1, C1)), "")
You could also have Excel evaluate B1 and C1 as if they contained text, as is done here:
=IF(A1=1, IF(B1&C1="", "", IF(B1>C1, B1, C1)), "")
This formula won't work as expected if either B1 or C1 contain a single space, so you might want to add the TRIM function into the mix:
=IF(A1=1, IF(TRIM(B1&C1)="", "", IF(B1>C1, B1, C1)), "")
In any of the formulas discussed so far, you may also want to change the IF statement that returns B1 or C1 with the MAX function, in this manner:
=IF(A1=1, IF(TRIM(B1&C1)="", "", MAX(B1:C1)), "")
There is one caveat if you decide to do this, however: The MAX function considers all text values to be equivalent to 0. Thus, if cell B1 contains "abc" and cell C1 contains 1, then using the greater than comparison operater (>) considers "abc" as greater than 1, but MAX considers 1 as greater than "abc".
There is also a way that you could go back and use Graham's original formula (the one that doesn't check for two blank cells) and simply rely on formatting the cell containing the formula. Just create a custom format such as the following:
m/d/yyyy;;
Notice the two semicolons at the end of the format. These tell Excel to not display anything if the value in the cell is negative or a zero value. Using this format, you would never see the date 1/0/1900 appear; the cell would show as blank.
You could, of course, modify Excel so that it hides all zero values in the worksheet—as has been covered in other ExcelTips—but doing so may not suit your purposes if you need to display zero results from other formulas.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10386) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
If your company closes out its accounting months at the end of each calendar quarter, figuring out the proper closing ...
Discover MoreWant to know which day of the month is the first business day? The easiest way to determine the date is to use the ...
Discover MoreWhen you have a huge amount of daily data to analyze, you may want to calculate an average of values for any given date ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-11-08 06:32:50
jamies
Also need to consider that what you expect to be zero, or what is displayed as zero may be a floating point value that, when rounded wound display as zero.
e.g. 0.00000000000001, -0.0000000000001, or if cash with 2 decimal places 0.00499999
And there is the annoyance that a General format cell will show 0 when set by a formula to be ""
So -
if testing for a value
=if((ABS(variable-value)<0.0000000000001),
And then there is the 0 that shows from =IF(1=1,"","") in an fi
Maybe
=IF(1=1, TEXT(,""),"")
Also for a cell value that should contain a value, but might be empty
A1 containing the text result wanted force the result to be considered a text string
=IF(1=1,""&A1,"")
But - whatever you use - do check it is properly considered by COUNT,), COUNTA() and other things'
IFERROR(testme,setting) now seems to require both a test value and the setting for the result.
Also a cell containing a setting such as a format, but no entered value may not be considered empty by some functions.
And - as always, consider compatibility with other workbook management and display/reporting Apps -
e.g. PDF
and if others are using the workbook Excel versions
2010 2013, 2019, 2022, 2024 - or not subscription or Apple/Mac versions, or on phones, as well as the excel.com variants.
2020-10-25 00:58:50
Alex B
The tip already covers many permutations. A couple of other things you could consider and using this version as an example, =IF(A1=1, IF((B1+C1=0), "", IF(B1>C1, B1, C1)), ""), are:
Consolidating the criteria returning "" as in
=IF(OR(A1<>1,B1+C1=0), "", IF(B1>C1, B1, C1))
and/or using the newer IFS function
=IFS(A1<>1,"",B1+C1=0, "", B1>C1, B1, TRUE,C1)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments