Written by Allen Wyatt (last updated May 12, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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 discernable 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. 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 (7092) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding the Date Associated with a Negative Value.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
When processing some text data, you may need to perform some esoteric function, such as adding dashes between letters. ...
Discover MoreWant to add an ordinal suffix to a number, as in 2nd, 3rd, or 4th? Excel doesn't provide a way to do it automatically, ...
Discover MoreWant to figure out how far it is between two points on the globe? If you know the points by latitude and longitude, you ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-05-23 19:44:15
José Martínez
Hello Allen,
Thank you so much for this tip. I'm working on something somewhat related.
I have two values in cells K (on hand) and L (on order), which added make for available quantity.
Then I have 24 columns, M thru AJ, which represent monthly demand buckets.
So I need to determine at which monthly column, my available quantity becomes negative.
For example, K2 = 10 + L2 = 10. Demand is M2=10, N2=5, P2=10, and so on.
So the 20 available (K2 + L2), become negative at column P (added demand by month P = 25 - 20 initially available = -5).
I need the header at P1 (month's name).
How may I do this in VBA code and then reference the function in a cell, like you describe above?
Thank you for your time and help,
José Martínez
2018-05-23 19:35:38
José Martínez
Hello Allen,
Thank you so much for this tip. I'm working on something somewhat related.
I have two values in cells K (on hand) and L (on order), which added make for available quantity.
Then I have 24 columns, M thru AJ, which represent monthly demand buckets.
So I need to determine at which monthly column, my available quantity becomes negative.
For example, K2 = 10 + L2 = 10. Demand is M2=10, N2=5, P2=10, and so on.
So the 20 available (K2 + L2), become negative at column P (added demand by month P = 25 - 20 initially available = -5).
I need the header at P1 (month's name).
How may I do this in VBA code and then reference the function in a cell, like you describe above?
Thank you for your time and help,
José Martínez
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments