+ Reply to Thread
Results 1 to 5 of 5

Match Last Occurrence of Numeric Value and Count BACK to Previous

  1. #1
    Sam via OfficeKB.com
    Guest

    Match Last Occurrence of Numeric Value and Count BACK to Previous

    Hi All,

    I wish to locate the LAST occurrence of a numerical value and Count BACK to
    the PREVIOUS time it appeared (counting the number of Rows between the Last
    and the Previous occurrence) and have that POSITION or COUNT Returned from
    within an 8 Column Dynamic Range called "Data".

    Name Refers To Box: Data
    =OFFSET(Actual!$C$2,0,0,COUNT(Actual!$C:$C),8)

    I've received help with similar scenarios but I cannot return the correct
    answer.

    Thanks
    Sam

    --
    Message posted via OfficeKB.com
    http://www.officekb.com/Uwe/Forums.a...tions/200511/1

  2. #2
    Domenic
    Guest

    Re: Match Last Occurrence of Numeric Value and Count BACK to Previous

    If the numerical value will never appear more than once in any row,
    try...

    =SUM(LARGE(IF(Data=A1,ROW(Data)-MIN(ROW(Data))+1),{1,2})*{1,-1})-1

    Otherwise, try...

    =SUM(LARGE(IF(MMULT(--(Data=A1),TRANSPOSE(COLUMN(Data)^0)),ROW(Data)-MIN(
    ROW(Data))+1),{1,2})*{1,-1})-1

    ....where A1 contains the numerical value of interest. Note that both
    formulas need to be confirmed with CONTROL+SHIFT+ENTER.

    Hope this helps!

    In article <57cff1c611a19@uwe>, "Sam via OfficeKB.com" <u4102@uwe>
    wrote:

    > Hi All,
    >
    > I wish to locate the LAST occurrence of a numerical value and Count BACK to
    > the PREVIOUS time it appeared (counting the number of Rows between the Last
    > and the Previous occurrence) and have that POSITION or COUNT Returned from
    > within an 8 Column Dynamic Range called "Data".
    >
    > Name Refers To Box: Data
    > =OFFSET(Actual!$C$2,0,0,COUNT(Actual!$C:$C),8)
    >
    > I've received help with similar scenarios but I cannot return the correct
    > answer.
    >
    > Thanks
    > Sam


  3. #3
    Registered User
    Join Date
    11-23-2005
    Posts
    70

    Cool Last and 2ns last occurance

    I've posted a small file for you. This small file shows how to get the row numbers of the last and 2nd last occurances of numbers in a column. It uses 3 columns other than the data column, but if you want you can merge the formulas.

    http://www.anywhereenterprises.com:8...OWOAApQZOAAY5i

  4. #4
    Sam via OfficeKB.com
    Guest

    Re: Match Last Occurrence of Numeric Value and Count BACK to Previous

    Hi Domenic,

    Thank you very much indeed; that worked Great.

    >If the numerical value will never appear more than once in any row,
    >try...


    >=SUM(LARGE(IF(Data=A1,ROW(Data)-MIN(ROW(Data))+1),{1,2})*{1,-1})-1


    >...where A1 contains the numerical value of interest. Note that both
    >formulas need to be confirmed with CONTROL+SHIFT+ENTER.


    Cheers,
    Sam


    Domenic wrote:
    >If the numerical value will never appear more than once in any row,
    >try...
    >
    >=SUM(LARGE(IF(Data=A1,ROW(Data)-MIN(ROW(Data))+1),{1,2})*{1,-1})-1
    >
    >Otherwise, try...
    >
    >=SUM(LARGE(IF(MMULT(--(Data=A1),TRANSPOSE(COLUMN(Data)^0)),ROW(Data)-MIN(
    >ROW(Data))+1),{1,2})*{1,-1})-1
    >
    >...where A1 contains the numerical value of interest. Note that both
    >formulas need to be confirmed with CONTROL+SHIFT+ENTER.
    >
    >Hope this helps!
    >
    >> Hi All,
    >>

    >[quoted text clipped - 11 lines]
    >> Thanks
    >> Sam


    --
    Message posted via OfficeKB.com
    http://www.officekb.com/Uwe/Forums.a...tions/200511/1

  5. #5
    Sam via OfficeKB.com
    Guest

    Re: Match Last Occurrence of Numeric Value and Count BACK to Previous

    Hi rsenn,

    Thank you for providing a sample file, it was very helpful.

    Cheers,
    Sam

    rsenn wrote:
    >I've posted a small file for you. This small file shows how to get th
    >row numbers of the last and 2nd last occurances of numbers in a column
    >It uses 3 columns other than the data column, but if you want you ca
    >merge the formulas.
    >
    >http://www.anywhereenterprises.com:8...sOWOAApQZOAAY5


    --
    Message posted via OfficeKB.com
    http://www.officekb.com/Uwe/Forums.a...tions/200511/1

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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