Match Last Occurrence of Numeric Value and Count BACK to Previous

  • Thread starter Sam via OfficeKB.com
  • Start date
S

Sam via OfficeKB.com

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
 
D

Domenic

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!
 
S

Sam via OfficeKB.com

Hi Domenic,

Thank you very much indeed; that worked Great.
If the numerical value will never appear more than once in any row,
try...

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

Cheers,
Sam

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!
[quoted text clipped - 11 lines]
Thanks
Sam
 
S

Sam via OfficeKB.com

Hi rsenn,

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

Cheers,
Sam
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top