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 August 4, 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)

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

Formatting Combo Box Text

If you insert objects, such as a combo box, in your worksheet, you may need a way to modify the font used in the object. The ...

Discover More

Replacing a Colon in a Sequence

Sometimes you'll run across the need to replace a very specific sequence of characters in your document. It is for these ...

Discover More

An Average that Excludes Zero Values

Excel allows you to use functions and formulas to analyze your data. One way you can analyze your data is to use the AVERAGE ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Counting Odds and Evens

If you have a series of values in a range of cells, you may wonder how many of those values are even and how many are odd. ...

Discover More

Counting Jobs Completed On a Date

When you store the date and time in a single cell, it can be a bit confusing to count how many cells contain a particular ...

Discover More

Filling References to Another Workbook

When you create references to cells in other workbooks, Excel, by default, makes the references absolute. This makes it ...

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 8Mpixels. 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 7 - 0?

2015-03-08 06:51:05

Michael (Micky) Avidan

@Boss,
If you want to get a proper suggestion - upload your workbook to a file hosting site and let us know the direct link to it.
Within the sheet - present 2-3 typed sample results for 2-3 dates.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2015-03-08 04:45:16

Boss

I have to summarize data for entire month. the way to do it is by looking at the first and last value of each day for one month.

for instance, February second, first entry is "LPG-10234", last entry is "LPG-11678".

for each day, I have about 40 entries. and I have to sort them day by day like the example above for an entire month.

Ticket Date
LPG-10958 01-Feb-2015
LPG-10959 01-Feb-2015
LPG-10960 01-Feb-2015
LPG-10961 01-Feb-2015
LPG-10962 01-Feb-2015
LPG-10963 01-Feb-2015

LPG-11003 02-Feb-2015
LPG-11004 02-Feb-2015
LPG-11005 02-Feb-2015
LPG-11006 02-Feb-2015
LPG-11007 02-Feb-2015
LPG-11008 02-Feb-2015
LPG-11009 02-Feb-2015

and my summery should be like below

Date First Last
01-Feb-2015 LPG-10958 LPG-10963
02-Feb-2015 LPG-11003 LPG-11009

I am currently doing this manually in excel, and want to do this automatically.

Your help is appreciated


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.