Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. 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.

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, 2021, and Excel in Microsoft 365


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:

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 (12321) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel 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

Applying Consistent Shading to a Table

Formatting tables can be very time consuming. When you get a document from another person, you can spend a lot of time ...

Discover More

Fitting Text Into Cells

Need a way to make sure your text fits within the space available in a table cell? Word has a handy setting that will ...

Discover More

Inserting a Formatted Text Box with a Macro

Macros allow you to do just about anything in Word, but not if you limit yourself to using just the Macro Recorder. This ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Using SUMIF with Text Parameters

The SUMIF function is supposed to work just fine doing comparisons with text values. This isn't a hard-and-fast rule, ...

Discover More

Using the REPT Function

Excel includes a handy function that allows you to repeat characters or strings of characters. How you use the REPT ...

Discover More

Specifying Proper Case

If you need to change the case of letters in a cell, one of the functions you can use is the PROPER function. This tip ...

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}] (all 7 characters, in the sequence shown) 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 9 + 7?

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 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.

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.