• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Returning values left and right of specific characters|General Excel Questions & Answers|Excel Forum|My Online Training Hub

You are here: Home / Returning values left and right of specific characters|General Excel Questions & Answers|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumGeneral Excel Questions & Answe…Returning values left and right of …
sp_PrintTopic sp_TopicIcon
Returning values left and right of specific characters
Avatar
Doug Richards
Member
Members
Level 0
Forum Posts: 19
Member Since:
December 1, 2020
sp_UserOfflineSmall Offline
1
January 20, 2021 - 3:17 am
sp_Permalink sp_Print

I have attached a partial of a file with the columns I'm having an issues with. On the worksheet you will find two sections:

This worksheet generates new codes for a product.

First is the data section the second is the Lookup table that I am using, this is a sample data but represents the format.

The data section is a copy of data only, no formulas or lookup to the lookup table, I do have questions on the excel sheet of what I hope explains what I am trying to do.

Column A is the primary column and where I enter the code manually, column "B" & "C" are the new codes that will be generated combining columns, First letter from column "A", column "I" and column "H". Other columns are for quick reference and reporting.

Column E is all characters to the left of the first "-".

The #N/A in rows 4&5, columns "E" & "F" is because these rows don't have an entry in column "G".

Really need help on getting column "E" and "G", but any and all suggestions would be appreciated.

Avatar
SunnyKow
Puchong, Malaysia

VIP
Members


Trusted Members
Level 8
Forum Posts: 1432
Member Since:
June 25, 2016
sp_UserOfflineSmall Offline
2
January 20, 2021 - 6:28 pm
sp_Permalink sp_Print

Not very clear about your column G.

You should show us what formulas you are using and what are your expected answers in case of #N/A.

It is very difficult for us to guess. 

Anyway, give this a try.

Cell B2 : =LEFT(A2,1)&I2&H2

Cell E2 : =IFERROR(LEFT(A2,FIND("-",A2)-1),A2)

Cell F2 : =VLOOKUP(G2,Table1,3,FALSE)

Cell G2 : =IFERROR(MID(A2,FIND("-",A2)+1,99),"CONV")

Cell H2 : =VLOOKUP(G2,Table1,4,FALSE)

Good luck.

Sunny

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 615
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
3
January 20, 2021 - 9:10 pm
sp_Permalink sp_Print

FWIW, you could simplify E2 to:

=LEFT(A2,FIND("-",A2&"-")-1)

Avatar
Doug Richards
Member
Members
Level 0
Forum Posts: 19
Member Since:
December 1, 2020
sp_UserOfflineSmall Offline
4
January 21, 2021 - 5:48 am
sp_Permalink sp_Print

Thank you Sunny and Velouria.

Here are my formulas:

Cell B2 =LEFT([@[RT Line Code]],1)&[@[Auto Incremtal ]]&[@[Trait_ID]]

Cell E2 =IF([@[Trait_Family_Code]]="X",[@[RT Line Code]],LEFT(A3, FIND("-", A3)-1))

Cell F2 =XLOOKUP([@[Trait_Family]],Trait_ID[Trait],Trait_ID[Trait_Family_Code])

Cell G2 is a manual entry at this time, will try your suggestions and let you know.

Cell H2 =XLOOKUP(G3,Trait_ID[Trait],Trait_ID[Trait_ID])

 

All formulas you have shared work great, thank you very much.

Now my only issue is how do I auto increment column "I", it being an alphanumeric entry and then when it gets to AA99, it advances to BA01 and starts the count over.  This might just stay a manually entered cell.

I thank you again for the help.

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 615
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
5
January 21, 2021 - 6:51 pm
sp_Permalink sp_Print

What happens if you get to ZA99?

Avatar
Doug Richards
Member
Members
Level 0
Forum Posts: 19
Member Since:
December 1, 2020
sp_UserOfflineSmall Offline
6
January 22, 2021 - 12:23 am
sp_Permalink sp_Print

Well, good question, on present additions x 2 to the file, that will take about 50 years, I hopefully wouldn't have to worry about it by then.

That is why I'm might not work about doing it, but it would be fun to try and find out how to do it.

Avatar
SunnyKow
Puchong, Malaysia

VIP
Members


Trusted Members
Level 8
Forum Posts: 1432
Member Since:
June 25, 2016
sp_UserOfflineSmall Offline
7
January 22, 2021 - 2:35 am
sp_Permalink sp_Print

Hi Doug

If your data is in an Excel Table, then you can give this a try.

In cell I2 enter : 

=IFERROR(IF(MID(I1,3,2)<>"99",LEFT(I1,2)&VALUE(MID(I1,3,2))+1,CHAR(CODE(LEFT(I1,1))+1)&"A"&1),"AA1")

As you add new row, the formula will auto fill downwards.

You can try change the 99 to maybe 5 or 10 just to check if the increment is OK.

Hope this helps.

Sunny

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Roslyn Finlayson, Shanna Henseler, LAN H
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6210
Posts: 27236

 

Member Stats:
Guest Posters: 49
Members: 31888
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.