ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Match Last Occurrence of Numeric Value and Count BACK to Previous (https://www.excelbanter.com/excel-worksheet-functions/57064-match-last-occurrence-numeric-value-count-back-previous.html)

Sam via OfficeKB.com

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

Domenic

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


rsenn

Match Last Occurrence of Numeric Value and Count BACK to Previous
 

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


--
rsenn
------------------------------------------------------------------------
rsenn's Profile: http://www.excelforum.com/member.php...o&userid=29050
View this thread: http://www.excelforum.com/showthread...hreadid=487810


Sam via OfficeKB.com

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

Sam via OfficeKB.com

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


All times are GMT +1. The time now is 04:52 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com