+ Reply to Thread
Results 1 to 5 of 5

Index a result which is the value above a threshold in a time range on a date

Hybrid View

  1. #1
    Registered User
    Join Date
    01-14-2024
    Location
    England
    MS-Off Ver
    Office 365
    Posts
    2

    Index a result which is the value above a threshold in a time range on a date

    Hi,

    Seeing if anyone can help me here as my Excel skills are average at best!

    I am looking for a formula to do the following:

    Display the specific time when a value crosses a set threshold for the first time within a specific timerange on a specific date.

    My research had prodouced the formula below so far:

    =IFERROR(INDEX($B$2:$B$28,MATCH(TRUE,($A$2:$A$28>G2)*($B$2:$B$28>=D2)*($B$2:$B$28<=E2)*($C$2:$C$28=F2),0)),"No match")

    The columns on my sheet are A is list of values, B List of times, C List of dates, D Start time, E End Time, F Specific date, G is Threshold value.

    This may be totally wrong im not sure. All I know is it doesnt work.

    I have attached the sheet with all this in.

    Any help appreciated

    Many Thanks Ross
    Attached Files Attached Files

  2. #2
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,182

    Re: Index a result which is the value above a threshold in a time range on a date

    This would do it:
    Formula: copy to clipboard
    =TAKE(FILTER(B2:B28,(C2:C28=F2)*(B2:B28>=D2)*(B2:B28<=E2)*(A2:A28>=G2)),1)


    That said, none of the times are true numeric time values, and none of the dates are true numeric date values. They are all text values that look a bit like dates and times. You can check by changing the format to General. If they change to numbers, they are true dates/times. If they don't, they're not.

    Edit:
    Formula: copy to clipboard
    =TAKE(FILTER(B2:B28,(C2:C28=F2)*(B2:B28>=D2)*(B2:B28<=E2)*(A2:A28>=G2),"no match"),1)


    copes with the target value not being found.
    Last edited by TMS; 01-14-2024 at 01:27 PM.
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  3. #3
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,182

    Re: Index a result which is the value above a threshold in a time range on a date

    Incidentally, this also works for non 365:
    Formula: copy to clipboard
    =IFERROR(INDEX($B$2:$B$28,MATCH(1,($A$2:$A$28>G2)*($B$2:$B$28>=D2)*($B$2:$B$28<=E2)*($C$2:$C$28=F2),0)),"No match")

  4. #4
    Registered User
    Join Date
    01-14-2024
    Location
    England
    MS-Off Ver
    Office 365
    Posts
    2

    Re: Index a result which is the value above a threshold in a time range on a date

    Thanks for the response that works great

    Much appreciated

    Ross

  5. #5
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,182

    Re: Index a result which is the value above a threshold in a time range on a date

    You're welcome.



    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

+ 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. Replies: 1
    Last Post: 11-30-2016, 08:02 PM
  2. Replies: 3
    Last Post: 09-20-2016, 03:13 PM
  3. Index outside named range does not result in error?!
    By ssteenstraten in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 01-12-2014, 05:00 PM
  4. [SOLVED] Find the first time a threshold value is exceed in an unsorted range
    By NotMyName in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 09-11-2013, 05:02 AM
  5. Assigning Threshold to time format
    By Locust in forum Excel General
    Replies: 4
    Last Post: 02-27-2011, 01:01 PM
  6. Calculating % of time that values fall over a threshold
    By greyscale in forum Excel General
    Replies: 2
    Last Post: 02-03-2011, 11:31 PM
  7. Index Using Threshold Value
    By chaz in forum Excel General
    Replies: 3
    Last Post: 05-22-2006, 09:50 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