Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Finding the Date Associated with a Negative Value.

Finding the Date Associated with a Negative Value

by Allen Wyatt
(last updated November 11, 2017)

2

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Changing the Way Endnotes Are Numbered

Word is flexible on how it numbers your endnotes. This tip shows how easy it is to make the changes to the numbering system.

Discover More

Automatic Lines for Dividing Lists

When preparing a report for others to use, it is not unusual to add a horizontal line between major sections of the ...

Discover More

Adding Diagonal Borders

Want to add a border diagonally, through the middle of a table cell? It's easy if you follow the formatting steps ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (menu)

Extracting First and Last Words

When working with text phrases stored in cells, it might be helpful to be able to extract words from the phrase. In this ...

Discover More

Pulling Initial Letters from a String

When working with names or a different series of words, you may need to pull the initial letters from each word in the ...

Discover More

Getting a Count of Unique Names

When you've got a column full of names, you may want to get a count of how many of those names are unique. You can make ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 3 - 2?

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


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.