Code generation formula

rameshppc

Board Regular
Joined
Jun 10, 2017
Messages
114
Office Version
  1. 2013
Platform
  1. Windows
S NO
CODE NUMBER
MOBILE NUMBER
REFERING NUMBER
1
6375871156
2
3

<tbody>
</tbody>

Hi good morning,

I need your help for making the above chart as smart.

I am giving a offer to my customers, who are purchasing mobile phones in our shop.

I want to give a unique offer code to each mobile phone purchasing customer and tel them to refer some one to purchase mobile in our shop by bring the offer code.

Now i will fill the "c" & "d" column with the customer mobile number, and i need a code "b" column.

The code generation will be as like,
if, the mobile number is 6375871156
Then, first three number 6+3+7 = 16
then, next three number 5+8+7 = 20
then, next three number 1+1+5 = 7
last one digit "6" = F (6th digit in alphabet)
Now i need the code as 16207F

Hope you will understand what i am expecting. I am ready to explain you more if my above request not clear for you.

Advance thanks.
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
=SUM(--MID(LEFT(A1,3),{1,2,3},1))&SUM(--MID(MID(A1,4,3),{1,2,3},1))&SUM(--MID(MID(A1,7,3),{1,2,3},1))&CHAR(64+RIGHT(A1))

ctrl shift enter run the formula.
 
Upvote 0
Hi i am getting #value ! even i use ctrl shift enter.

I think the "a1" you mentioned is the phone number I wrote in "c2" right?
 
Upvote 0
yes, A1 in my formula means the cell contains the phone number.
 
Upvote 0
Code:
=sum(--mid(left(c2,3),{1,2,3},1))&sum(--mid(mid(c2,4,3),{1,2,3},1))&sum(--mid(mid(c2,7,3),{1,2,3},1))&char(64+right(c2))
 
Upvote 0
shaowu459 formula is working fine & neat. If you wish to avoid using array formula you can use the below

=MID(C2,1,1)+MID(C2,2,1)+MID(C2,3,1)&MID(C2,4,1)+MID(C2,5,1)+MID(C2,6,1)&MID(C2,7,1)+MID(C2,8,1)+MID(C2,9,1)&CHAR(64+RIGHT(C2))
 
Upvote 0
shaowu459 formula is working fine & neat. If you wish to avoid using array formula you can use the below

=MID(C2,1,1)+MID(C2,2,1)+MID(C2,3,1)&MID(C2,4,1)+MID(C2,5,1)+MID(C2,6,1)&MID(C2,7,1)+MID(C2,8,1)+MID(C2,9,1)&CHAR(64+RIGHT(C2))

Yes, normal formula is OK.

In office 365, we can also use CONCAT or TEXTJOIN:

Code:
=CONCAT(MMULT(--MID(C2,{1,2,3}+{0;3;6},1),{1;1;1}))&CHAR(64+RIGHT(C2))
 
Upvote 0

Forum statistics

Threads
1,214,621
Messages
6,120,563
Members
448,972
Latest member
Shantanu2024

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
Back
Top