Return Consecutive Values

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

Sam via OfficeKB.com

Hi All,

I am using the formula below to return one specific value referenced in an
input cell B1:

=IF((COUNTIF(INDEX(Stock,ROW()-ROW(Stock)+1,0),B$1))=1,B$1,"")

How might a more suitable formula or the above formula be expanded to find
pairs of consecutive values in ascending order in a Dynamic Defined Range
“Stock” ( 7 Columns B-H and many Rows), and return the two consecutive
values on the same Row in separate columns (side by side) on a new sheet.

Sample Data – Defined Dynamic Range “Stock”:
COL B C D E F G H
ROW19 70 72 87 88 89 92 95
ROW20 73 74 78 80 81 83 84

In case data is misaligned: Row 19, Column B, C, D, E, F, G, and H houses
70, 72, 87, 88, 89, 92 and 95 respectively. Row 20, Column C, D, E, F, G,
and H houses 73 74, 78, 80, 81, 83 and 84 respectively.

New Worksheet (for Expected Results)
ROW1 Input cells: B$1, C$1, D$1, E$1, F$1, G$1, H$1, I$1, J$1, K$1
80 81 82 83 84 85 86 87 88 89

In case data is misaligned: cell B1, C1, D1, E1, F1, G1, H1, I1, J1 and K1
house 80, 81, 82, 83, 84, 85, 86, 87, 88 and 89

Expected Results:
COL B C D E F G H I J K
ROW19 88 89
ROW20 83 84

Row19 – 88 and 89 returned in columns J and K
Row20 – 83 and 84 returned in columns E and F

Kind Regards,
Sam
 
D

Domenic

I haven't fully tested it, but see if this will do...

Assuming that Sheet1 contains your source data, and Sheet2 contains your
expected results...

1) If there will always be at least one set of consecutive pairs...

Sheet2!B19, copied across and down:

=IF(INDEX(Sheet1!$B19:$G19,MATCH(2,1/(Sheet1!$C19:$H19-Sheet1!$B19:$G19=1
)))=B$1,SUM(B$1,A19),IF(COUNTIF($A19:A19,">0")=1,SUM(A19,1),""))

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

2) If there may not be at least one consecutive pair...

Sheet2!B19, copied across and down:

=IF(1-ISNA(MATCH(2,1/(Sheet1!$C19:$H19-Sheet1!$B19:$G19=1))),IF(INDEX(She
et1!$B19:$G19,MATCH(2,1/(Sheet1!$C19:$H19-Sheet1!$B19:$G19=1)))=B$1,SUM(B
$1,A19),IF(COUNTIF($A19:A19,">0")=1,SUM(A19,1),"")),"")

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

Hope this helps!
 
D

Domenic

I forgot to mention that this will only work if Column A on Sheet2
(starting at A19 onwards) is either blank or contains text values.

Hope this helps!
 
B

Biff

Hi Domenic!

Change the values in Sheet1 row 19 to:

85:91

Sheet2 row 19 = ""

This is a real challenge!

Biff
 
D

Domenic

Hi Biff!

Biff said:
Change the values in Sheet1 row 19 to:

85:91

Sheet2 row 19 = ""

Thanks for catching it! Much appreciated!
This is a real challenge!

Most definitely! And I do like a challenge! :)

Here's my second attempt at a solution. This time I hope I've covered
all the bases. I guess we'll see... :)

Sheet2!B19, copied across and down:

=IF(INDEX(Sheet1!$B19:$G19,MATCH(2,1/((Sheet1!$C19:$H19-Sheet1!$B19:$G19=
1)*(Sheet1!$B19:$G19>=80)*(Sheet1!$C19:$H19<=89))))=B$1,SUM(B$1,A19),IF(C
OUNTIF($A19:A19,">0")=1,SUM(A19,1),""))

....confirmed with CONTROL+SHIFT+ENTER. Note that the same caution
applies here. Column A, starting at A19, must either be blank or
contain text values.

Hope this helps!
 
S

Sam via OfficeKB.com

Hi Domenic,

Thank you for assistance and ongoing help.

I'm using your suggested 2nd option below - the formula did not return all
the instances of expected consecutive values. I've just picked up on Biff's
posting and your amended version - so I'll post back shortly.

Thanks
Sam
-------------------------------------------------------------------------

2) If there may not be at least one consecutive pair...
Sheet2!B19, copied across and down:

=IF(1-ISNA(MATCH(2,1/(Sheet1!$C19:$H19-Sheet1!$B19:$G19=1))),IF(INDEX(She
et1!$B19:$G19,MATCH(2,1/(Sheet1!$C19:$H19-Sheet1!$B19:$G19=1)))=B$1,SUM(B
$1,A19),IF(COUNTIF($A19:A19,">0")=1,SUM(A19,1),"")),"")

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

Sam via OfficeKB.com

Hi Domenic,

Thank you very much for sample file. Your interpretation of what I said is
perfect and the file does what I requested. However, as usual, I did not
fully understand what I actually wanted to see visually on the new
worksheet - Sheet2.

I still require the consecutive values to be returned to Sheet2 by using
the input values on Row 1 of Sheet2 but I need all consecutive values
returned by individual pairs and not by individual numbers. Using the
current formula I would get 82-83-84-85-86-87-88. There are instances where
a Row may contain all consecutive values as below, and what I actually wish
to see is all instances for example of 82-83, 83-84, 84-85, 85-86, 86-87
and 87-88. I'm not sure whether having two columns for each input value
would help.

Is there a way to achieve the above?

Sheet1!B19:H19 contains...
82 83 84 85 86 87 88

Sheet2!B1:K1 contains..
80 81 82 83 84 85 86 87 88 89


Thanks
Sam
 
D

Domenic

Assumptions:

1) Each row in the source table (Sheet1) contains unique values.

2) Each row in the source table contains values in ascending order.

Formula:

B19, copied down and across to J19:

=IF(ISNUMBER(MATCH(B$1,Sheet1!$B19:$H19,0)),IF(MATCH(B$1,Sheet1!$B19:$H19
,0)<7,IF(INDEX(Sheet1!$B19:$H19,MATCH(B$1,Sheet1!$B19:$H19,0)+1)=B$1+1,B$
1&"-"&B$1+1,""),""),"")

Hope this helps!
 
S

Sam via OfficeKB.com

Hi Domenic,

Thank you very much for all your help. The formula works great - brilliant!


Thanks
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

Similar Threads

Scrabble Value calculation for Welsh words 0
Return Consecutive Values - Pairs 6
scatter plot 2
Nested if using range names 1
Nested If statement or lookup? 1
VLOOKUP 2
VLookup 8
Formula for non matching items 3

Top