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
Thomas_DE
Regular Visitor

Referencing data from another row

I have a Table with the following structure

TitleEntryData
A10MasterData 1
A23SpecialData
A54null
B10MasterData 2
B34null
B576null
C10null
C21312null


What i want to achieve in Power Query M is that for some entries in the table i have "MasterData" which is always under Entry "10" for the corresponding Title, some may also have SpecialData which i don´t want to touch...

 

The Table i would want to have would be like this:

TitleEntryData
A10MasterData 1
A23SpecialData
A54MasterData 1
B10MasterData 2
B34MasterData 2
B576MasterData 2
C10null
C21312null

 

So i would need to somehow reference always the Data from Entry "10" for all null values of the same title data. It could also be in a new added column if that´s easier. Filldown is not helping in this case either unfortunately because i cannot restrict it to the same Title. I just found a working formula replacing the null value with an value of the same row... how can i shift that reference to always return the corresponding Title "10" Entry if there is one?

 

= Table.AddColumn(#"xxx", "Data", each if [Data] = null then [Entry] else [Data], type text)

This "[Entry]" i would need to point to the corresponding 10 entry of the same title...

 

Any hint how to do that is very appreciated! Thanks!

1 ACCEPTED SOLUTION
wdx223_Daniel
Super User
Super User

NewStep=Table.Combine(Table.Group(PreviousStepName,"Title",{"n",each Table.ReplaceValue(_,"","",(x,y,z)=>x??_{[Entry=10]}?[Data],{"Data"})})[n])

View solution in original post

3 REPLIES 3
wdx223_Daniel
Super User
Super User

NewStep=Table.Combine(Table.Group(PreviousStepName,"Title",{"n",each Table.ReplaceValue(_,"","",(x,y,z)=>x??_{[Entry=10]}?[Data],{"Data"})})[n])

Thanks! This is working as I need it, I don´t understand it yet but I´ll go through it step by step till i do.

jbwtp
Memorable Member
Memorable Member

Hi @Thomas_DE,

 

I think this does what you are after. Please try.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI0ABK+icUlqUUuiSWJCoZKsToQGSNjIBFckJqcmZgDkoJLmJoAibzSnBywiBMWQ4zgMsYYak3NzZCFnGHaUUSMDI0NjeCCsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Title = _t, Entry = _t, Data = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Title", type text}, {"Entry", Int64.Type}, {"Data", type text}}),
    fTransform = (t as table) as table =>
        let 
            Transform = List.Skip(List.Accumulate(Table.ToRecords(t), {{null, {}}}, (a, n)=>  a &  (if n[Entry] = 10 then {{n[Data], n }} else {{List.Last(a){0}, if n[Data]="null" then Record.TransformFields(n, {{"Data", (x)=> List.Last(a){0}}}) else n }}))),
            Output = Table.FromRecords(List.Zip(Transform){1}, Value.Type(t))
        in
            Output,
    next = #"Changed Type",
    #"Grouped Rows" = Table.Combine(Table.Group(next, {"Title"}, {{"Count", fTransform}})[Count])
    in #"Grouped Rows"

 

 

Kind regards,

John

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