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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
JNelson
Helper II
Helper II

Grouping Function Power Query

Hello all,

 

I think this is a basic grouping action however I can't get it to work. Or I may need to pivot or have a conditional statement in, but was hoping someone would be able to assist.

 

I have a data set of sales where, if there are multiple rows for a single day and code, I want to SUM the Qty column relating to the Date and the Code and for the summed value to populate in the corresponding row that has A in column A or P. And to leave the corresponding Qty cell (where column [A or P] is P) blank. The order of [A and P] is not always A on top so may need sorting? But don't want to mess up the data. Example of desired outcome below, and data table provided.

 

JNelson_0-1713400783159.png

 

1 ACCEPTED SOLUTION
AlienSx
Super User
Super User

hello, @JNelson group and expand operations may shuffle data so add index column to sort by in the end if you like.

let
    Source = your_table,
    fx = (tbl) => 
        if Table.RowCount(tbl) = 1 
        then tbl
        else Table.FromRecords(
            Table.TransformRows(
                tbl, 
                (x) => Record.TransformFields(
                    x, 
                    {"Qty", each if x[A or P] = "A" then List.Sum(tbl[Qty]) else null}
                )
            )
        ),
    group = Table.Group(
        Source, 
        {"Date", "Code"}, 
        {{"x", fx}}),
    xp_tbl = Table.ExpandTableColumn(group, "x", {"Type", "Qty", "Q2", "A or P"})
in
    xp_tbl

View solution in original post

3 REPLIES 3
dufoq3
Super User
Super User

Hi @JNelson, different approach here.

 

Before

dufoq3_1-1713454908340.png

 

After

dufoq3_2-1713454919913.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrTQNzDRNzIwMlHSUTIEYv+izPTMvMQcINPYwABImoMIR6VYHSyKA4ryQSosgIQlSFkApjIjIPZxKlaAKDW0sASSpviVIjnBxBxImEEcEAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Code = _t, Type = _t, Qty = _t, Q2 = _t, #"A or P" = _t]),
    ChangedType = Table.TransformColumnTypes(Source,{{"Qty", Int64.Type}, {"Q2", Int64.Type}, {"Date", type date}}),
    GroupedRows = Table.Group(ChangedType, {"Date", "Code"}, {{"All", each Table.AddColumn(_, "Sum Qty", (x)=> List.Sum([Qty]), Int64.Type), type table [Date=nullable date, Code=nullable text, Type=nullable text, Qty=nullable number, Q2=nullable number, A or P=nullable text]}}),
    CombinedAll = Table.Combine(GroupedRows[All]),
    ReplacedQty = Table.ReplaceValue(CombinedAll,
        each [A or P] = "A",
        each [Sum Qty],
        (x,y,z)=> if y then z else null,
        {"Qty"} ),
    RestoreDataTypes = Value.ReplaceType(ReplacedQty, Value.Type(CombinedAll)),
    RemovedColumns = Table.RemoveColumns(RestoreDataTypes,{"Sum Qty"})
in
    RemovedColumns

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

AlienSx
Super User
Super User

hello, @JNelson group and expand operations may shuffle data so add index column to sort by in the end if you like.

let
    Source = your_table,
    fx = (tbl) => 
        if Table.RowCount(tbl) = 1 
        then tbl
        else Table.FromRecords(
            Table.TransformRows(
                tbl, 
                (x) => Record.TransformFields(
                    x, 
                    {"Qty", each if x[A or P] = "A" then List.Sum(tbl[Qty]) else null}
                )
            )
        ),
    group = Table.Group(
        Source, 
        {"Date", "Code"}, 
        {{"x", fx}}),
    xp_tbl = Table.ExpandTableColumn(group, "x", {"Type", "Qty", "Q2", "A or P"})
in
    xp_tbl
wdx223_Daniel
Super User
Super User

NewStep=let a=Table.Group(PreivousStepName,{"Date","Code"},{"n",each if Table.RowCount(_)>1 then List.Sum([Qty]) else null}) in Table.ReplaceValue(PreviousStepName,each _,"",(x,y,z)=>let b= a{[Date=y[Date],Code=y[Code]]}[n] in if b=null then x else if y[A or P]="A" then b else null,{"Qty"}) 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors