Character Limitation formula help needed

pstrucks

New Member
Joined
Aug 20, 2019
Messages
2
Maximum Length20
Product Information- User InputGenerated SKU Code & Product Explanation
Product CategoryProduct NameAttribute1Attribute2Attribute3Product ExplanationGenerated SKU CodeModified SKU Code
SAS PTPC5" Screw Philips headUM5115xxxx5" Screw Philips head-UM-5115-xxxx5"SCREW-UM-511-XXX5"SCREW-UM-511-XXX

<colgroup><col><col><col span="3"><col><col><col></colgroup><tbody>
</tbody>

The formula for the SKU code generated is:
= UPPER(SUBSTITUTE(IF(RIGHT(SUBSTITUTE(SUBSTITUTE(CONCATENATE(LEFT(SUBSTITUTE(B13," ",""),CEILING.MATH($E$10/3)),"-",LEFT(SUBSTITUTE(C13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(D13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(E13," ",""),CEILING.MATH($E$10/7))),"--","-"),"--","-"),1)="-", REPLACE(SUBSTITUTE(SUBSTITUTE(CONCATENATE(LEFT(SUBSTITUTE(B13," ",""),CEILING.MATH($E$10/3)),"-",LEFT(SUBSTITUTE(C13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(D13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(E13," ",""),CEILING.MATH($E$10/7))),"--","-"),"--","-"),LEN(SUBSTITUTE(SUBSTITUTE(CONCATENATE(LEFT(SUBSTITUTE(B13," ",""),CEILING.MATH($E$10/3)),"-",LEFT(SUBSTITUTE(C13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(D13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(E13," ",""),CEILING.MATH($E$10/7))),"--","-"),"--","-")),1,""),SUBSTITUTE(SUBSTITUTE(CONCATENATE(LEFT(SUBSTITUTE(B13," ",""),CEILING.MATH($E$10/3)),"-",LEFT(SUBSTITUTE(C13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(D13," ",""),CEILING.MATH($E$10/7)),"-",LEFT(SUBSTITUTE(E13," ",""),CEILING.MATH($E$10/7))),"--","-"),"--","-"))," ",""))

I would like to be able to make a 12NC SKU code having xxxx-xxxx-xxxx but the current formula is only allowing the XXX on the final 3 stages of the SKU code that is generated. Does any one have an idea on how to alter the above formula to increase the character limit from xxx to xxxx?
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
I could not find a reference for 12NC SKU code. There are likely rules that specify exactly how to create the code but without knowing them this answer is a guess. The only reference I could implied that 12NC stood for 12 Number Code ... which you are not generating (due to presence of letters)

Apparently the formula is in G13 and the Max length in E10.

Examining the formula...looks like formula enforces no double dashes and no periods. The existing formula limits each attribute to no more than 3 characters. I did not include that limit here. if that is a requirement then the formula can be changed or you can add data validation in columns C:E to limit the length of the input to 4 characters.

I believe this formula will do what you ask:
Code:
=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(B13," ",""),"-",""),$E$10-LEN(SUBSTITUTE(SUBSTITUTE("-"&C13&"-"&D13&"-"&E13," ",""),"--","-"))) &SUBSTITUTE(SUBSTITUTE("-"&C13&"-"&D13&"-"&E13," ",""),"--","-"))

Breaking down the major chunks
Code:
SUBSTITUTE(SUBSTITUTE("-"&C13&"-"&D13&"-"&E13," ",""),"--","-")
concatenates the attributes and a leading dash for each then removes the any spaces and replaces any double dash with a single dash. This will return a double dash if all attributes are blank. This is referred to as X in the next chunk explanation

Code:
LEFT(SUBSTITUTE(SUBSTITUTE(B13," ",""),"-",""),$E$10-LEN(X))
Remove spaces and dashes from the product name then take enough of the leftmost characters to make the total length of the SKU equal to the number in E10 or fewer.

If this does not produce the desired results please provide more sample inputs with desired outputs.
 
Upvote 0

Forum statistics

Threads
1,214,830
Messages
6,121,835
Members
449,051
Latest member
excelquestion515

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