Log in

View Full Version : Return a comment based on values in another cell



msiyab
05-13-2015, 02:06 PM
Hi Guys,

I have a file with invoice numbers (over 120k). Each invoice number has a prefix (ex. PM1401-121312). Where 14 is the year 2014 & 01 is January month and the rest is the invoice number. So I want to know a formula which would give me the month (in MMM-YY format) next to the invoice number by just taking 1401 into consideration. The prefixes change and so is the spacing and formatting based on the entry done by employees. However, 1401 or 1402 remains the same.

Waiting for a reply.

Thanks

Siyab

LalitPandey87
05-13-2015, 03:48 PM
Can you show the sample with different formatting. It helps to understand your problem well.

msiyab
05-13-2015, 04:07 PM
PM1401-121312 - Jan 2014
CM1402-54543 - Feb 2014
RXBF1405-222 - May 2014
CT1412TY-12 - Dec 2014

Admin
05-13-2015, 09:22 PM
Assume your Invoice number in A2, in B2

=TEXT(TEXT(--("20"&MID(A2,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")),4)&"01"),"0000\/00\/00")+0,"mmm yy")

msiyab
05-14-2015, 10:50 AM
Thank you very much, it helped.

:cheers:

Rick Rothstein
05-23-2015, 02:47 AM
Assume your Invoice number in A2, in B2

=TEXT(TEXT(--("20"&MID(A2,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")),4)&"01"),"0000\/00\/00")+0,"mmm yy")
Here is a similar formula that is eight characters and one fuction call less than the formula you posted..

=TEXT(0+(20&REPLACE(MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),4),3,0,"-")&"-01"),"mmm yy")

I would note, though, that one could put this even shorter formula in the cell (saves another 15 characters and one more function call)...

=0+(20&REPLACE(MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),4),3,0,"-")&"-01")

and simply Custom Format the cells using "mmm yy" (without the quote marks, of course)... doing it that way, the cells will contain real dates, instead of Text that looks like a date, and which can be used directly in other formulas if need be.