+ Reply to Thread
Results 1 to 7 of 7

Finding smallest and largest gaps in list of dates.

  1. #1
    Registered User
    Join Date
    03-08-2008
    Posts
    6

    Finding smallest and largest gaps in list of dates.

    I have a long list of dates (in order, in one column; oldest at the top), about 240, which are entered when an event happens. These might happen twice in one day, or have a gap of several months. What I'd like to be able to do is find the smallest and biggest gap between dates.

    So I'm guessing a means of searching down the list, comparing each with the one before (above) it, and finding the smallest gap in the list (probably 0) and the largest. If it could also be modified to search certain date ranges within the list (e.g. the previous 12 months) that would be excellent, but not vital

    Very grateful for any and all help, this has proven very tricky

  2. #2
    Forum Expert
    Join Date
    02-19-2013
    Location
    India
    MS-Off Ver
    07/16
    Posts
    2,386

    Re: Finding smallest and largest gaps in list of dates.

    Attach a sample workbook. Make sure there is just enough data to demonstrate your need. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are shown, mock them up manually if necessary.

    Remember to desensitize the data.

    Click on GO ADVANCED and use the paperclip icon to open the upload window.

    View Pic
    -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

    WANT TO SAY THANKS, HIT ADD REPUTATION (*) AT THE BOTTOM LEFT CORNER OF THE POST

    More we learn about excel, more it shows us, how less we know about it.

    for chemistry
    https://www.youtube.com/c/chemistrybyshivaansh

  3. #3
    Registered User
    Join Date
    03-08-2008
    Posts
    6

    Re: Finding smallest and largest gaps in list of dates.

    Thanks, I've attached a quick example.

    EDIT: well I thought I had, it shows up in preview post, but not when I posted?
    Attached Files Attached Files
    Last edited by ajay1965; 02-20-2016 at 08:44 AM.

  4. #4
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Finding smallest and largest gaps in list of dates.

    In your file you say the longest gap is 24 days.

    However, I believe the correct result is 77 days.

    Cell A111 = 7/28/2013
    Cell A112 = 10/13/2013

    Difference is 77 days.

    Both formulas need to be array entered**.

    For the longest gap:

    =MAX(A2:A119-A1:A118)

    For the shortest gap:

    =MIN(A2:A119-A1:A118)

    ** array formulas need to be entered using the key
    combination of CTRL,SHIFT,ENTER (not just ENTER).
    Hold down both the CTRL key and the SHIFT key
    then hit ENTER.
    Biff
    Microsoft MVP Excel
    Keep It Simple Stupid

    Let's Go Pens. We Want The Cup.

  5. #5
    Registered User
    Join Date
    03-08-2008
    Posts
    6

    Re: Finding smallest and largest gaps in list of dates.

    Thank you very much, that's great. Is there anyway of doing it when you have an ever increasing list, i.e. where you don't know the max list of dates?

    Thanks again

  6. #6
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Finding smallest and largest gaps in list of dates.

    =MAX(A2:INDEX(A:A, MATCH(--"12/31/9999",A:A )) - A1:INDEX(A:A, MATCH(--"12/31/9999",A:A ) - 1))

    Still confirmed with CSE.
    Entia non sunt multiplicanda sine necessitate

  7. #7
    Registered User
    Join Date
    03-08-2008
    Posts
    6

    Re: Finding smallest and largest gaps in list of dates.

    That's excellent shg; is there also a way to MATCH from a date, e.g. instead of up to 12/31/9999, but from today()-365 to 12/31/1999? Many thanks.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Finding largest date from 3 different dates
    By welchs101 in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 08-17-2015, 03:43 PM
  2. finding 10 smallest unique values in a list
    By reggie1000 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 10-03-2008, 08:59 PM
  3. Find 7th largest and smallest element in unsorted list
    By cpadude in forum Excel General
    Replies: 2
    Last Post: 06-24-2008, 05:22 PM
  4. Finding largest number from list
    By holyman in forum Excel General
    Replies: 1
    Last Post: 07-23-2006, 07:00 PM
  5. Finding the 3rd largest number in a list
    By N Harkawat in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 09-06-2005, 12:05 PM
  6. Finding the 3rd largest number in a list
    By Simon Jefford in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-05-2005, 11:05 PM
  7. COMPARE DATA AND LIST SMALLEST AND LARGEST ENTRY BY UNIT
    By Dwain A, louisiana in forum Excel General
    Replies: 3
    Last Post: 08-05-2005, 12:05 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1