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! Learn more

Reply
Anonymous
Not applicable

Add new column with IF-ELSE condition in Power Query

I have table as the one on the left below and would like to transform into the one on the right based on the following condition:

 

If MTH is 9,10 or 11, sum all the PRICE (SUM all PRICE for MTH 9, SUM all PRICE for MTH 10, SUM all PRICE for MTH 11)

Else, sum the PRICE and divide by 12 (SUM all PRICE for MTH 8 then divide 12, SUM all PRICE for MTH 12 then divide 12)

 

Aziz_Arrashid_0-1637605818762.png

 

Really appreciate any help on how to do it in power query.

1 ACCEPTED SOLUTION

Hi @Anonymous ,
Here are the pics, might by in reverse order. 

Groupby to get your sums, then divide by 12 to get your division, the use conditional col to decide which col to use.  Then delete intermediate columns.

Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel

new col1234.PNGnew col123.PNGnew col12.PNGnew col1.PNG





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

4 REPLIES 4
ronrsnfld
Super User
Super User

You can do this all in a single aggregation within the Table.Group function:

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table3"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{
        {"ACT/FC", type text}, {"MTH", Int64.Type}, {"TYPE", type text}, {"PRICE", Int64.Type}}),
    
    group = Table.Group(#"Changed Type","MTH",{
        "PRICE", each 
            if List.Contains({9..11},[MTH]{0}) 
                then List.Sum([PRICE]) 
                else List.Sum([PRICE])/12, type number
    })
in
    group

 

ronrsnfld_0-1637625401530.png

 

 

 

 

Nathaniel_C
Community Champion
Community Champion

Hi @Anonymous Try this, paste this into your advanced editor.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WslDSUTJUitWBsIzALEsgyxjOMgGzDA2ATFME0wzCNAQyzRFMCwjTCMi0RDCBGmJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [M = _t, Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"M", Int64.Type}, {"Column1", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"M"}, {{"Sum", each List.Sum([Column1]), type nullable number}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Divide", each [Sum]/12),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom",{{"Divide", type number}}),
    #"Added Conditional Column" = Table.AddColumn(#"Changed Type1", "Custom", each if [M] = 9 or  [M] = 10 or  [M] = 11 then [Sum] else if [M] = 8  or  [M] = 12 then [Divide] else null),
    #"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column",{"Sum", "Divide"})
in
    #"Removed Columns"


Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel

 

Will follow up with pic





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Hi @Anonymous ,
Here are the pics, might by in reverse order. 

Groupby to get your sums, then divide by 12 to get your division, the use conditional col to decide which col to use.  Then delete intermediate columns.

Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel

new col1234.PNGnew col123.PNGnew col12.PNGnew col1.PNG





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Source tableSource table





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
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!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

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 Kudoed Authors