Return Row Number of LAST Numeric Consecutive Duplicate in Column

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

Sam via OfficeKB.com

Hi All,

Using a Dynamic Named Range "Data", I would like a Formula to return the Row
Number of the "LAST" instance of a duplicate numeric value - repeating twice
consecutively in the same column.

Thanks
Sam
 
D

Domenic

Just to be clear, if A2:A10 contains the following data...

6
6
9
3
5
7
7
7
4

....what would be your expected result?
 
S

Sam via OfficeKB.com

Hi Domenic,

A column will contain multiple instances of the same numerical value, so A2:
A10 will contain only numeric value 30. This numeric value will at times have
consecutive duplicates (x2).

Cheers,
Sam
 
D

Domenic

Are you saying that A2:A10 might look something like this... ?

30


30
30


30
30

If so, what result would you expect? And to be clear, will there ever
be an instance where there's three or more consecutive values?
 
S

Sam via OfficeKB.com

Hi Domenic,
Are you saying that A2:A10 might look something like this... ?
Yes



30
30 Row Number of LAST 30 with two consecutive instances
If so, what result would you expect? And to be clear, will there ever
be an instance where there's three or more consecutive values?

I would expect the Row Number of the LAST 30 with two consecutive instances.
There may be instances with three or more consecutive values BUT I only
require the LAST Row Number of those with two consecutive instances.

Cheers,
Sam
 
D

Domenic

First, assuming that Sheet1, Column A, starting at A2, contains the
data, change the reference for the defined named 'Data' to...

=Sheet1!$A$2:INDEX(Sheet1!$A$2:$A$65536,MATCH(9.99999999999999E+307,Sheet
1!$A$2:$A$65536)+1)

Then, let B2 contain the number of interest, such as 30, and try the
following formula which needs to be confirmed with CONTROL+SHIFT+ENTER,
not just ENTER...

=LOOKUP(2,1/(FREQUENCY(IF(Data=B2,ROW(Data)-MIN(ROW(Data))+1),IF(Data<>B2
,MATCH(ROW(Data),ROW(Data),0),B2+1))=2),ROW(Data))-1

Note that if you'd like to check for the last instance of 3 consecutive
values, change =2 to =3, and so on.

Hope this helps!
 
S

Sam via OfficeKB.com

Hi Domenic,

Thank you for your time and assistance.

Your Formulae does work but I forgot to say the Dynamic Named Range "Data"
spans many columns. Based on the orginal scenario I would like to have the
relevant Row Number from these columns also returned. Can your Formulae be
adjusted to facilitate this.

Apologies for incomplete explanation.

Cheers,
Sam
Minor change...
 
D

Domenic

Let's assume that Sheet1, Columns A, B, and C, starting at Row 2,
contains the data, let E2 contain the value of interest, such as 30,
then try the following...

Select F2

Insert > Name > Define

Name: Data2

Refers to:

=Sheet1!A$2:INDEX(Sheet1!A$2:A$65536,MATCH(9.99999999999999E+307,Sheet1!A
$2:A$65536)+1)

Click OK

Change the references accordingly. Then, enter the following formula in
F2, and copy across:

=LOOKUP(2,1/(FREQUENCY(IF(Data2=$E2,ROW(Data2)-MIN(ROW(Data2))+1),IF(Data
2<>$E2,MATCH(ROW(Data2),ROW(Data2),0),ROWS(Data2)+1))=2),ROW(Data2))-1

....confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!
 
S

Sam via OfficeKB.com

Hi Domenic,

Thank you very much for all your help. The Formulae works Great!

Cheers,
Sam
Let's assume that Sheet1, Columns A, B, and C, starting at Row 2,
contains the data, let E2 contain the value of interest, such as 30,
then try the following...

Select F2

Insert > Name > Define

Name: Data2

Refers to:

=Sheet1!A$2:INDEX(Sheet1!A$2:A$65536,MATCH(9.99999999999999E+307,Sheet1!A
$2:A$65536)+1)

Click OK

Change the references accordingly. Then, enter the following formula in
F2, and copy across:

=LOOKUP(2,1/(FREQUENCY(IF(Data2=$E2,ROW(Data2)-MIN(ROW(Data2))+1),IF(Data
2<>$E2,MATCH(ROW(Data2),ROW(Data2),0),ROWS(Data2)+1))=2),ROW(Data2))-1

...confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!
Hi Domenic,
[quoted text clipped - 9 lines]
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