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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Reuben
Helper III
Helper III

grab text and put it in another column

Hi all,

I am trying to resolve the following problem in the query:

I have a basic dim product table composed of:

SKU: 5 digit code. The first 3 digit can be numeric or alphanumeric. The las two digit are the subdivision and are always numeric, starting from 01,02, 03... to 99

Description: Each 5 digit SKU has a different description.

SKU 3 Digit: Same as SKU excluding the subdivision number.

What I want to do is to grab the description of the last SKU number, and create another column displaying this description in every "SKU 3 digit".

As my english is quite bad, let me explain it with an example:

Captura.PNG

 

Thank you for your support

RB

 

2 ACCEPTED SOLUTIONS
Jimmy801
Community Champion
Community Champion

Hallo @Reuben 

 

add a new column with this formula (The variable PreviousStep you have to exchange with your last step name)

Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description]

Here a complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1NTBU0lFyBGIgWylWByJmBOQ7oYkZg9QhK3S0MDQwBfINDUAyFoZwQTOQIEwsFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Description = _t, #"SKU 3 digit" = _t]),
    PreviousStep = Table.TransformColumnTypes(Source,{{"SKU", type text}, {"Description", type text}, {"SKU 3 digit", type text}}),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Description new", each Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description])
in
    #"Added Custom"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

Jimmy801
Community Champion
Community Champion

Hello @Reuben 

 

you can try this code... maybe it has some better performance

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1NTBU0lFyBGIgWylWByJmBOQ7oYkZg9QhK3S0MDQwBfINDUAyFoZwQTOQIEwsFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Description = _t, #"SKU 3 digit" = _t]),
    PreviousStep = Table.Buffer(Table.TransformColumnTypes(Source,{{"SKU", type text}, {"Description", type text}, {"SKU 3 digit", type text}})),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Description new", each Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description])
in
    #"Added Custom"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

8 REPLIES 8
Reuben
Helper III
Helper III

awsome!! the evaluation time has been reduced from >10 min to 2 min. Thank you!!

Reuben
Helper III
Helper III

thank you guys for all your help.

I feel bad cause I cannot select all the answers as solution!

I have tried all the option and they work just perfect in the desktop.

But I have to explore why the same M code it doesn't work in the Service query (dataflow). I get a Timeout error when executing the last step. So I guess my table is too large and I have some kind of limitation.

thanks again for your time

Anonymous
Not applicable

Try this. I changed table max. with table.last (I suppose find last element of list instead of max could, almost shure, improve the performance).

the problem could be if your table is not well ordered, as I supposed. my solutione was more general.

How many rows your data set has?

 

let
    Origine = Tabella,
    #"Rimosse altre colonne" = Table.SelectColumns(Origine,{"SKU", "Description"}),
    #"Suddividi colonna in base alla posizione" = Table.SplitColumn(#"Rimosse altre colonne", "SKU", Splitter.SplitTextByPositions({0, 3}, false), {"SKU.1", "SKU.2"}),
    #"Raggruppate righe" = Table.Group(#"Suddividi colonna in base alla posizione", {"SKU.1"}, {{"descold", each _[Description] },{"descnew", each List.Last(_[Description]) } }),
    #"Tabella descold espansa" = Table.ExpandListColumn(#"Raggruppate righe", "descold")
in
    #"Tabella descold espansa"

 

Jimmy801
Community Champion
Community Champion

Hello @Reuben 

 

you can try this code... maybe it has some better performance

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1NTBU0lFyBGIgWylWByJmBOQ7oYkZg9QhK3S0MDQwBfINDUAyFoZwQTOQIEwsFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Description = _t, #"SKU 3 digit" = _t]),
    PreviousStep = Table.Buffer(Table.TransformColumnTypes(Source,{{"SKU", type text}, {"Description", type text}, {"SKU 3 digit", type text}})),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Description new", each Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description])
in
    #"Added Custom"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Jimmy801
Community Champion
Community Champion

Hallo @Reuben 

 

add a new column with this formula (The variable PreviousStep you have to exchange with your last step name)

Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description]

Here a complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjU1NTBU0lFyBGIgWylWByJmBOQ7oYkZg9QhK3S0MDQwBfINDUAyFoZwQTOQIEwsFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [SKU = _t, Description = _t, #"SKU 3 digit" = _t]),
    PreviousStep = Table.TransformColumnTypes(Source,{{"SKU", type text}, {"Description", type text}, {"SKU 3 digit", type text}}),
    #"Added Custom" = Table.AddColumn(PreviousStep, "Description new", each Table.Last(Table.SelectRows(PreviousStep, (row)=> Text.Start(row[SKU],3)=_[SKU 3 digit]))[Description])
in
    #"Added Custom"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

Anonymous
Not applicable

 

let
    Origine = Tabella,
    #"Rimosse altre colonne" = Table.SelectColumns(Origine,{"SKU", "Description"}),
    #"Suddividi colonna in base alla posizione" = Table.SplitColumn(#"Rimosse altre colonne", "SKU", Splitter.SplitTextByPositions({0, 3}, false), {"SKU.1", "SKU.2"}),
    #"Raggruppate righe" = Table.Group(#"Suddividi colonna in base alla posizione", {"SKU.1"}, {{"descold", each _[Description] },{"descnew", each List.Max(_[Description]) } }),
    #"Tabella descold espansa" = Table.ExpandListColumn(#"Raggruppate righe", "descold")
in
    #"Tabella descold espansa"

 

 

 

image.png

v-alq-msft
Community Support
Community Support

Hi, @Reuben 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

e1.png

 

You may create a new custom column with the following m codes.

let 
x=[SKU 3 digit],
newtab=Table.AddColumn(#"Added Custom","SKU last 2 digit",each Number.From( Text.End([SKU],2))),
tab=Table.SelectRows(newtab,each [SKU 3 digit]=x),
val=Table.Max(tab,"SKU last 2 digit")[Description]
in 
val

e2.png

 

Result:

e3.png

 

Best Regards

Allan

 

If this post helps,then consider Accepting it as the solution to help other members find it faster.

CNENFRNL
Community Champion
Community Champion

Hi, @Reuben , you might want to try this solution in PQ; in addition, Excel formula, our oldie but goodie, can solve it with ease. I attach an Excel file for your further reference.

Excel FormulaExcel FormulaPQPQ


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors