Formula

shaylynch

Board Regular
Joined
Nov 11, 2002
Messages
163
Hi all,
i am looking for assisstance on creating a formula that will create a project code using information out of 3 different cells.Eg, i have attached a sheet below and what i am trying to achieve is to create a Project Code by using the the first 2 letters of the clients name, followed by the last letter, then the project number in a 3 number format, eg, 5 is 005, 12 is 012 etc and then finally, from the project name cell, the first letter of each name, in the example below it works out at BLS005DIY. i know it sounds a bit tricky, but if anyone can help it would be much appreciated. oh and finally, if it could all be kept in capitals, it would be fantastic!!

thanks in advance

Shay
Business Database.xls
EFGH
16ProjectCodeProjectNameClientProjectNo.
17BLS005DIYDoItYourselfBloggers5
New Project
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Hi shaylynch,

I Managed to get to ...
BLS005D
... Using the Formula ...
=UPPER(LEFT(G17,2)&RIGHT(G17,1))&TEXT(H17,"000")&UPPER(LEFT(F17,1))
... But have got Stuck on the Last Two Letters.
I am Sure Somebody Else will be Able to Help Complete this.

All the Best.
SHADO
 
Upvote 0
Personally I'd stick this in a custom function:
Code:
Public Function GetProjectCode(ByVal pClient As String, ByVal pProjectNum As Integer, ByVal pProjectName As String) As String
    Dim arTemp, i As Integer
    
    GetProjectCode = Left(pClient, 2) & Right(pClient, 1)
    GetProjectCode = GetProjectCode & Format(pProjectNum, "000")
    arTemp = Split(pProjectName, " ")
    For i = LBound(arTemp) To UBound(arTemp)
        If Len(arTemp(i)) > 0 Then GetProjectCode = GetProjectCode & Left(arTemp(i), 1)
    Next
    
    GetProjectCode = UCase(GetProjectCode)
End Function
 
Upvote 0
This is not to Difficult until you get to the First Letter of every word in the project name. You CAN do it using manipulation of MID, FIND, and ISERROR, but the formula gets huge and inflexible. I opted for a slightly easier route. Do the following formula.

A1= Whirlpool Corporation
A2 = 001
A3 = Dryer Site Of Power

=UPPER(LEFT(A1,2)&RIGHT(A1,1)&B1&ABBRVT(C1))


You will notice that it uses an ABBRVT funtion. This is a custom function I use for myself. Here is the code:
Code:
Function ABBRVT(S As String, Optional P As Boolean)
Dim X As Long
Dim S2 As String
S = Trim(S)
S2 = Mid(S, 1, 1)
If P = True Then S2 = S2 & Chr(46)
For X = 2 To Len(S)
    If Mid(S, X, 1) = Chr(32) Then
        S2 = S2 & Mid(S, X + 1, 1)
        If P = True Then S2 = S2 & Chr(46)
        End If
Next X
Abbreviate = StrConv(S2, 1)
End Function
 
Upvote 0
Re Formula

hi Guys,
thanks for your help,i got stuck in the same place SHADO and had a feeling it would get messy after that with a formula. the function looks cool but i have only 1 issue, i am quite illeterate when it comes to code. how do i implement a function, do i just put it in a module in VB? or is there anything else i need to do

Thanks Again

Shay
 
Upvote 0
Open the workbook. Press ALT-F11 to open the VBE. On the insert menu insert the module. Paste the code into the module. Save. The function will now be available for that workbook.
 
Upvote 0
Hi Oorang,
i am sorry to be a pain, but that is what i have been trying and it's not working.i completely understand what you have done and once the ABBRVT has been defined as a function in VB, it should relate it to the formula.
I have definitely saved the vb in the correct workbook space and created a new module for it

thanks again

Shay
 
Upvote 0
Good morning Oorang,
when i open VB, i created a new module and pasted the code into it (in that workbook). i also used the formula to calculate the project code, but it is only calculating the formula part and not the code using the ABBRVT function

Shay
 
Upvote 0

Forum statistics

Threads
1,214,605
Messages
6,120,476
Members
448,967
Latest member
visheshkotha

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