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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Fcoatis
Post Patron
Post Patron

Power Query filter simulating IN VALUES

Hello all,

I know to to create a reduced table in Table View using this code:

 

CGJOBS Reduced = CALCULATETABLE(CGJOBS, CGJOBS[JOB] IN VALUES (realocJOBS [JOB]))

But I need to create the same reduced table from a copy of the original CGJOBS in query mode using M code. Any suggestion?

Thanks in advance.

1 ACCEPTED SOLUTION
v-juanli-msft
Community Support
Community Support

Hi @Fcoatis 

Copy CGJOBS and paste in Edit queries, then we get a table CGJOBS(2),

Merge queries in CGJOBS(2), 

3.png

Expand "JOB" , then remove blank values

1.png2.png

let
    Source = Excel.Workbook(File.Contents("C:\Users\maggiel\Desktop\case\8\8.2\8.2.xlsx"), null, true),
    CGJOBS_Sheet = Source{[Item="CGJOBS",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(CGJOBS_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"JOB", Int64.Type}, {"value", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"JOB"}, realocJOBS, {"JOB"}, "realocJOBS", JoinKind.LeftOuter),
    #"Expanded realocJOBS" = Table.ExpandTableColumn(#"Merged Queries", "realocJOBS", {"JOB"}, {"realocJOBS.JOB"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded realocJOBS", each [realocJOBS.JOB] <> null and [realocJOBS.JOB] <> ""),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"realocJOBS.JOB"})
in
    #"Removed Columns"

Best Regards
Maggie

 

Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-juanli-msft
Community Support
Community Support

Hi @Fcoatis 

Copy CGJOBS and paste in Edit queries, then we get a table CGJOBS(2),

Merge queries in CGJOBS(2), 

3.png

Expand "JOB" , then remove blank values

1.png2.png

let
    Source = Excel.Workbook(File.Contents("C:\Users\maggiel\Desktop\case\8\8.2\8.2.xlsx"), null, true),
    CGJOBS_Sheet = Source{[Item="CGJOBS",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(CGJOBS_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"JOB", Int64.Type}, {"value", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"JOB"}, realocJOBS, {"JOB"}, "realocJOBS", JoinKind.LeftOuter),
    #"Expanded realocJOBS" = Table.ExpandTableColumn(#"Merged Queries", "realocJOBS", {"JOB"}, {"realocJOBS.JOB"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded realocJOBS", each [realocJOBS.JOB] <> null and [realocJOBS.JOB] <> ""),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"realocJOBS.JOB"})
in
    #"Removed Columns"

Best Regards
Maggie

 

Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors