Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Terp
Advocate III
Advocate III

Calculated Column: Return Two (2) Characters After Comma

I was trying to figure out how to do a reverse concantination, per se, and got close...but can't get it right. 🙂

 

I have a long string of city/MSA information and I want to join this city table to another (state-level) table and decided to use 'State Abbreviation' as the bridge...used a bunch of SWITCHes to make "Flordia" become "FL" in a new column, for example.

 

So in short, I want to take the value in the [City/MSA/MD] column and truncate it to return the first two letters after/to the right of the comma, which will form the 'State Abbreviation' column.

 

You can see I got the "FL" in there perfectly...but also everything thereafter. 🙂

 

Could someone point out the error in my ways, please? Should I use something else (lookups?) to get at the two letters after the comma? 

 

(I don't even want to address the MSAs that comprise MULTIPLE states, so just pulling the first two capital letters after the comma and assigning to that primary state...for now). lol

 

Terp_1-1655947483134.png

 

 

1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@Terp , On Top of your formula use left(<Current formula>,2)

I think that might help

View solution in original post

5 REPLIES 5
MPetramalo214
Helper I
Helper I

Can you try adding the LEFT function to what you already have? 

St Abbrv = 
LEFT (
    RIGHT ( [City/MSA/MD], LEN ( [City/MSA/MD] ) - FIND ( ", ", [City/MSA/MD] ) - 1 ),
    2
)

 This should get you the two characters on the left, of the text to the right of the comma. 

 

If you have a static number of states that an entry can be at most (ie. no more than two/three states), you could probably add a conditional to check the third digit from the left, and if its a "-" then you have two states, and return the first 5 characters, otherwise return the first 2.

Your genius is equally impressive, thanks! 🙂

 

'Left (right...' just didn't seem right. Thank you both for the help...never would have stumbbled on that one.

It does seem like a strange combination.. I went ahead and threw together a mockup of how you could go about getting multiple states.  This will only work if you have a static number of states; if its dynamic, then a bunch of nested if statements probably isn't efficient enough.

MPetramalo214_0-1655950113612.png

St Abbrv = 
var rightOfComma = RIGHT([Column2], LEN([Column2]) - FIND(", ", [Column2])-1)

var thirdChar = RIGHT(LEFT(rightOfComma, 3), 1)

return
IF(
    thirdChar = "-",
    LEFT(rightOfComma, 5),
    LEFT(rightOfComma, 2)
)
amitchandak
Super User
Super User

@Terp , On Top of your formula use left(<Current formula>,2)

I think that might help

You, sir, are a genius....would have NEVER gotten that one right...did swap out right for left previously and played around, but would have never thought to use both. 🙂

 

It doen't seem intuitive/efficient, but it sure works! Many, many thanks, sir!

 

Terp_0-1655949718398.png

 

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

Check out the February 2024 Power BI update to learn about new features.

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.