Edit Formula To Return Leading Zeroes

CARBOB

Well-known Member
Joined
Jun 6, 2005
Messages
1,860
How do I get the formula in Col's F:J return the value for leading zeroes?
Excel Workbook
ABCDEFGHIJ
10212172136#N/ACSCS
21121323336DCCDS
31116182230DSSDS
40307102636#N/A#N/ACSS
Sheet2
Excel 2007
Cell Formulas
RangeFormula
F1=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(A1,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(A1,{1,2},1)+0)+{0,1},MID(A1,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(A1,{1,2},1)+0,MID(A1,{1,2},1)+0))))
F2=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(A2,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(A2,{1,2},1)+0)+{0,1},MID(A2,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(A2,{1,2},1)+0,MID(A2,{1,2},1)+0))))
F3=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(A3,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(A3,{1,2},1)+0)+{0,1},MID(A3,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(A3,{1,2},1)+0,MID(A3,{1,2},1)+0))))
F4=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(A4,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(A4,{1,2},1)+0)+{0,1},MID(A4,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(A4,{1,2},1)+0,MID(A4,{1,2},1)+0))))
G1=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(B1,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(B1,{1,2},1)+0)+{0,1},MID(B1,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(B1,{1,2},1)+0,MID(B1,{1,2},1)+0))))
G2=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(B2,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(B2,{1,2},1)+0)+{0,1},MID(B2,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(B2,{1,2},1)+0,MID(B2,{1,2},1)+0))))
G3=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(B3,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(B3,{1,2},1)+0)+{0,1},MID(B3,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(B3,{1,2},1)+0,MID(B3,{1,2},1)+0))))
G4=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(B4,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(B4,{1,2},1)+0)+{0,1},MID(B4,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(B4,{1,2},1)+0,MID(B4,{1,2},1)+0))))
H1=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(C1,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(C1,{1,2},1)+0)+{0,1},MID(C1,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(C1,{1,2},1)+0,MID(C1,{1,2},1)+0))))
H2=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(C2,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(C2,{1,2},1)+0)+{0,1},MID(C2,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(C2,{1,2},1)+0,MID(C2,{1,2},1)+0))))
H3=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(C3,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(C3,{1,2},1)+0)+{0,1},MID(C3,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(C3,{1,2},1)+0,MID(C3,{1,2},1)+0))))
H4=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(C4,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(C4,{1,2},1)+0)+{0,1},MID(C4,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(C4,{1,2},1)+0,MID(C4,{1,2},1)+0))))
I1=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(D1,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(D1,{1,2},1)+0)+{0,1},MID(D1,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(D1,{1,2},1)+0,MID(D1,{1,2},1)+0))))
I2=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(D2,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(D2,{1,2},1)+0)+{0,1},MID(D2,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(D2,{1,2},1)+0,MID(D2,{1,2},1)+0))))
I3=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(D3,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(D3,{1,2},1)+0)+{0,1},MID(D3,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(D3,{1,2},1)+0,MID(D3,{1,2},1)+0))))
I4=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(D4,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(D4,{1,2},1)+0)+{0,1},MID(D4,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(D4,{1,2},1)+0,MID(D4,{1,2},1)+0))))
J1=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(E1,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(E1,{1,2},1)+0)+{0,1},MID(E1,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(E1,{1,2},1)+0,MID(E1,{1,2},1)+0))))
J2=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(E2,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(E2,{1,2},1)+0)+{0,1},MID(E2,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(E2,{1,2},1)+0,MID(E2,{1,2},1)+0))))
J3=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(E3,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(E3,{1,2},1)+0)+{0,1},MID(E3,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(E3,{1,2},1)+0,MID(E3,{1,2},1)+0))))
J4=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(E4,{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(E4,{1,2},1)+0)+{0,1},MID(E4,{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(E4,{1,2},1)+0,MID(E4,{1,2},1)+0))))
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,961
Office Version
  1. 365
Platform
  1. Windows
How are you storing the values in A1, A4 & B4 to show the leading zero in cell? Your formula works fine for me with the methods I've tried, formatting the cells as text or '02 in the cell.
 

CARBOB

Well-known Member
Joined
Jun 6, 2005
Messages
1,860
How are you storing the values in A1, A4 & B4 to show the leading zero in cell? Your formula works fine for me with the methods I've tried, formatting the cells as text or '02 in the cell.

Formatted the cells as 00, so the values from 1-9 show as 01,02,09. The workbook has 376,299 rows with such values.
 

CARBOB

Well-known Member
Joined
Jun 6, 2005
Messages
1,860

ADVERTISEMENT

Maybe

http://www.mrexcel.com/forum/showpost.php?p=2291656&postcount=4

=IF(OR(AND(ISNUMBER(MATCH({0,9},MID(TEXT(A1,"00"),{1,2},1)+0,0))),AND(ISNUMBER(MATCH(MIN(MID(TEXT(A1,"00"),{1,2},1)+0)+{0,1},MID(TEXT(A1,"00"),{1,2},1)+0,0)))),"C",INDEX({"S","D"},MAX(FREQUENCY(MID(TEXT(A1,"00"),{1,2},1)+0,MID(TEXT(A1,"00"),{1,2},1)+0))))


Thank you, I was entering the TEXT(A1,"00") in the wrong spot, thank you very much!!
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,961
Office Version
  1. 365
Platform
  1. Windows
What are the criteria for the formula, is there a thread on it's creation?

I thought I had an alternative that is much shorter, but a couple of results didn't match yours.
 

CARBOB

Well-known Member
Joined
Jun 6, 2005
Messages
1,860

ADVERTISEMENT

What are the criteria for the formula, is there a thread on it's creation?

I thought I had an alternative that is much shorter, but a couple of results didn't match yours.


The formula works like this, any 2-digit value that is consecutive( 12,09,01) returns a "C". Any 2-digit value that is a double digit value(11,22,33) returns a (D). All other 2-digit values will be an (S).

There was a thread with this formula, but I can't find it.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,961
Office Version
  1. 365
Platform
  1. Windows
So I was thinking on the right lines, I started with

=IF(ABS(INT(A1/10)-MOD(A1,10))=1,"C",IF(INT(A1/10)=MOD(A1,10),"D","S"))

resulting in "C" for 09 and 90, which technically is correct as 9 and 0 are not consecutive.

There are several ways to use 0 as a substitute for 10 in the consecutive sequence,

=IF(ISNUMBER(MATCH(ABS(INT(A1/10)-MOD(A1,10)),{1,9},0)),"C",IF(INT(A1/10)=MOD(A1,10),"D","S"))

looks fairly tidy compared to the others I've tried, and it matches your results (tested 00 through to 99).
 

CARBOB

Well-known Member
Joined
Jun 6, 2005
Messages
1,860
So I was thinking on the right lines, I started with

=IF(ABS(INT(A1/10)-MOD(A1,10))=1,"C",IF(INT(A1/10)=MOD(A1,10),"D","S"))

resulting in "C" for 09 and 90, which technically is correct as 9 and 0 are not consecutive.

There are several ways to use 0 as a substitute for 10 in the consecutive sequence,

=IF(ISNUMBER(MATCH(ABS(INT(A1/10)-MOD(A1,10)),{1,9},0)),"C",IF(INT(A1/10)=MOD(A1,10),"D","S"))

looks fairly tidy compared to the others I've tried, and it matches your results (tested 00 through to 99).

Fantastic, very nicely done, appreciate it!!!
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,961
Office Version
  1. 365
Platform
  1. Windows
Not sure which of the various formula will be most efficient with the size of your data set, but a couple more for you to try.

=LOOKUP(ABS(INT(A1/10)-MOD(A1,10)),{0,1,2,9},{"D","C","S","C"})

=INDEX({"D","C","S","C"},MATCH(ABS(INT(A1/10)-MOD(A1,10)),{0,1,2,9},1))


I've only tested for values up to 99, not sure how results would compare with anything above that if there is possibility of such values in your data.
 
Last edited:

Watch MrExcel Video

Forum statistics

Threads
1,133,643
Messages
5,660,044
Members
418,544
Latest member
Stefan Braem

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top