Home |
Search |
Today's Posts |
|
#1
![]() |
|||
|
|||
![]()
If I have a column of sorted consecutive Integers, can I search that column
and find cells that might be missing a consecutive Integer? We have a list of customer numbers and if we don't have a number in the sorted sequential order we want to be able to know that. Any help? |
#2
![]() |
|||
|
|||
![]()
CM wrote...
If I have a column of sorted consecutive Integers, can I search that column and find cells that might be missing a consecutive Integer? We have a list of customer numbers and if we don't have a number in the sorted sequential order we want to be able to know that. Any help? If you have a column of sorted integers in a range named LST in which all the integers should be consecutive, your first test should be whether there are any duplicates. That can be done using =SUMPRODUCT((LST<"")/(COUNTIF(LST,LST)+(LST="")))=COUNT(LST) If this returns TRUE, then all numbers in the list are distinct. Next, check that they're all integers. =SUMPRODUCT(--(MOD(LST,1)=0))=COUNT(LST) Once these two tests have been passed, it's simple to check if they're consecutive. =MAX(LST)-MIN(LST)=COUNT(LST)-1 If they're not, then the index within LST of the k_th nonconsecutive integer is given by the array formula =SMALL(IF(OFFSET(LST,0,0,COUNT(LST)-1,1)<OFFSET(LST,1,0,COUNT(LST)-1,1)-1, ROW(INDIRECT("2:"&ROWS(LST)))),k) |
#3
![]() |
|||
|
|||
![]()
Why not insert a helper column and calculate the difference between the two
values. "CM" wrote: If I have a column of sorted consecutive Integers, can I search that column and find cells that might be missing a consecutive Integer? We have a list of customer numbers and if we don't have a number in the sorted sequential order we want to be able to know that. Any help? |
#4
![]() |
|||
|
|||
![]()
This works with a starting value of 1000 in cell A2, so that the integer
MINUS 998 = the Row#, and returns the row of the first nonconsecutive integer: =MAX(--(A2:A28-998=ROW(A2:A28))*ROW(A2:A28)) "CM" wrote: If I have a column of sorted consecutive Integers, can I search that column and find cells that might be missing a consecutive Integer? We have a list of customer numbers and if we don't have a number in the sorted sequential order we want to be able to know that. Any help? |
#5
![]() |
|||
|
|||
![]()
And it needs to be entered as an array formula with
Ctrl-Shift-Enter "Duke Carey" wrote: This works with a starting value of 1000 in cell A2, so that the integer MINUS 998 = the Row#, and returns the row of the first nonconsecutive integer: =MAX(--(A2:A28-998=ROW(A2:A28))*ROW(A2:A28)) "CM" wrote: If I have a column of sorted consecutive Integers, can I search that column and find cells that might be missing a consecutive Integer? We have a list of customer numbers and if we don't have a number in the sorted sequential order we want to be able to know that. Any help? |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Ooh .. Linking a list to a list to an output cell | Excel Discussion (Misc queries) | |||
Update master list with other lists | Excel Worksheet Functions | |||
Search for most recent date from list of dates | Excel Discussion (Misc queries) | |||
Drop down List problems | Excel Discussion (Misc queries) | |||
Using advanced filter to search for criteria in a list | Excel Discussion (Misc queries) |