Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Finding the Date Associated with a Negative Value.
Written by Allen Wyatt (last updated July 30, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Stuart has a series of readings in a worksheet. In the first column he has dates associated with the readings and in the second column he has the actual readings. Stuart would like to have a formula that will return the first date at which a reading became negative. In other words, the formula should look for the first value that is negative in the second column and then return the date associated with that value. There can be multiple negative values in the second column, but he needs only the date associated with the first negative value.
There are a number of ways that this problem can be approached. All of the methods presume that the dates in column A are in ascending order and that the readings in column B are not in any type of discernible order. (In other words, the readings could bounce above and below 0 on any given date.)
Provided that you have some control over the layout of the worksheet, you could add an intermediate work column in column C, used to indicate when a value is negative. Simply place a formula like this in column C, to the right of each reading:
=IF(B1<0,A1,"")
This formula returns the date in column A if the value in B is below 0 (negative), otherwise it returns nothing. All you then need to do is look for the minimum value in column C:
=MIN(C:C)
Format the result as a date, and it represents the date at which the readings first became negative.
Another approach is to forego the use of the intermediate column and use an array formula to determine the date. Assuming the data is in the range A1:B42, you can use any of the following formulas:
=MIN(IF(B1:B42<0,A1:A42,"")) =OFFSET($A$1,MATCH(TRUE,$B$1:$B$42<0,0)-1,,,) =INDEX(A:A,MIN(IF(B1:B42<0,ROW(B1:B42)))) =INDEX(A1:A42,MATCH(TRUE,B1:B42<0,0)) =INDIRECT("A"&MIN(IF(B1:B42<0,ROW(B1:B42))),TRUE)
Remember that these are all array formulas, so you need to enter whichever one you choose by pressing Shift+Ctrl+Enter. (If you are using Excel 2021 or the version of Excel provided with Microsoft 365, you don't need to press Shift+Ctrl+Enter; you can just press Enter.) Format the result as a date, and it is the answer you seek.
If you prefer, you could also use a simple macro to determine the date:
Function GetFirstNegative(rngdata) Dim c As Variant For Each c In rngdata If c < 0 Then GetFirstNegative = c.Offset(0, -1) Exit Function Else GetFirstNegative = "All Data is Positive" End If Next End Function
In your worksheet, you would use this user-defined function in this manner:
=GetFirstNegative(B1:B42)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12321) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Finding the Date Associated with a Negative Value.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
If you need to know the number of columns in a particular range, you can use the COLUMNS worksheet function. This tip ...
Discover MoreCharacter codes are the numeric values used, by a computer, to signify various alphanumeric characters. You can use the ...
Discover MoreMost calculations are done using the decimal numbering system. If you need to convert your decimal values to a differing ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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