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)

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)

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

Non-Printing Hyperlinks

Karen is having problems getting hyperlinks to print in a document on her home computer. There are only a limited number of ...

Discover More

Printing Post Office Permits on Envelopes

When preparing to snail-mail information, you may want to print your envelopes with permit information in the upper-right ...

Discover More

Setting Spell-Checking Options

Like many things in Word, you can configure the way the spelling checker does its job. If you want to exercise more control ...

Discover More

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!

More ExcelTips (menu)

Where Is that Text?

Looking for a formula that can return the address of a cell containing a text string? Look no further; the solution is in ...

Discover More

How Operators are Evaluated

Operators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...

Discover More

Condensing Sequential Values to a Single Row

If you have a bunch of ZIP Codes or part numbers in a list, you may want to "condense" the list so that sequential series of ...

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 4 + 3?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.