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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
vedran
Frequent Visitor

New row based on previous row, ideas?

Hi there, I would like just ask for ideas.. have a transaction details table, and all details are in proper format expect 2 columns (Option and OptionAmount), goes like this:

 

TransDate | Customer | Product | Amount | Option | OptionAmount | Sum |

----------------------------------------------------------------------------------

2017/01/01    Cust1      Product1   40$        ABC               10$               50$

2017/01/01    Cust2      Product1   40$        ABC,DEF        15$               55$

 

Basically I would like to create new row, for every option, use all for transaction details from "parent row" but Option convert to Product, and for many Options I'll need to have create new rows (usually I have max 5-6 options in same cell) , for final results to have something like this

 

TransDate | Customer | Product | Amount | Option | OptionAmount | Sum |

----------------------------------------------------------------------------------

2017/01/01    Cust1      Product1   40$

2017/01/01    Cust1      ABC           10$

2017/01/01    Cust2      Product1   40$ 

2017/01/01    Cust2      ABC           10$

2017/01/01    Cust2      DEF            5$

 

Of course for OptionAmout I dont see any other solution than to have some kind of pricelist lookup, and that is not a big issue, main thing is how to create new rows in m-query based on Option column?

 

Any ideas?

 

Thank you all! Cheers!

1 ACCEPTED SOLUTION
MarcelBeug
Community Champion
Community Champion

Something like this:

 

let
    Source = TransactionDetails,
    #"Added Custom" = Table.AddColumn(Source, "ProductOptions", each Text.Split([Product]&","&[Option],","), type {text}),
    #"Expanded ProductList" = Table.ExpandListColumn(#"Added Custom", "ProductOptions"),
    #"Added Index" = Table.AddIndexColumn(#"Expanded ProductList", "Index", 0, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index",{"ProductOptions"},PriceList,{"Option"},"PriceList",JoinKind.LeftOuter),
    #"Expanded PriceList" = Table.ExpandTableColumn(#"Merged Queries", "PriceList", {"Price"}, {"PriceList.Price"}),
    #"Sorted Rows" = Table.Sort(#"Expanded PriceList",{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"}),
    #"Added Custom1" = Table.AddColumn(#"Removed Columns", "NewAmount", each if [Product] = [ProductOptions] then [Amount] else [PriceList.Price], type number),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom1",{"Product", "Amount", "Option", "OptionAmount", "Sum", "PriceList.Price"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns1",{{"ProductOptions", "Product"}, {"NewAmount", "Amount"}})
in
    #"Renamed Columns"
Specializing in Power Query Formula Language (M)

View solution in original post

2 REPLIES 2
MarcelBeug
Community Champion
Community Champion

Something like this:

 

let
    Source = TransactionDetails,
    #"Added Custom" = Table.AddColumn(Source, "ProductOptions", each Text.Split([Product]&","&[Option],","), type {text}),
    #"Expanded ProductList" = Table.ExpandListColumn(#"Added Custom", "ProductOptions"),
    #"Added Index" = Table.AddIndexColumn(#"Expanded ProductList", "Index", 0, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index",{"ProductOptions"},PriceList,{"Option"},"PriceList",JoinKind.LeftOuter),
    #"Expanded PriceList" = Table.ExpandTableColumn(#"Merged Queries", "PriceList", {"Price"}, {"PriceList.Price"}),
    #"Sorted Rows" = Table.Sort(#"Expanded PriceList",{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"}),
    #"Added Custom1" = Table.AddColumn(#"Removed Columns", "NewAmount", each if [Product] = [ProductOptions] then [Amount] else [PriceList.Price], type number),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom1",{"Product", "Amount", "Option", "OptionAmount", "Sum", "PriceList.Price"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns1",{{"ProductOptions", "Product"}, {"NewAmount", "Amount"}})
in
    #"Renamed Columns"
Specializing in Power Query Formula Language (M)

Marcel, I dont have better words except, thank you a lot!

This example goes in a perfect direction, I tried to recreate this example based on real data set, and works perfect.

 

Please I'd like to at least buy a beer or a lunch 🙂

 

Admins please add all Kudos to Marcel, and also this post I will to be marked as a Solution!

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors